summaryrefslogtreecommitdiffstats
path: root/dozentenmodulserver/src/main/java/org/openslx/bwlp/sat/database/Updater.java
blob: 0dcfac4f67b3f25a8473fbd8223bd42562c43bf4 (plain) (blame)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
package org.openslx.bwlp.sat.database;

import java.sql.ResultSet;
import java.sql.SQLException;

import org.apache.log4j.Logger;

public class Updater {

	private static final Logger LOGGER = Logger.getLogger(Updater.class);

	public static void updateDatabase() throws SQLException {
		addLocationPrivateField();
		addLectureLocationMapTable();
		addHasUsbAccessField();
		addLogTable();
		fixEmailFieldLength();
		addNetworkShares();
		addLectureFilter();
	}

	private static void addLectureLocationMapTable() throws SQLException {
		try (MysqlConnection connection = Database.getConnection()) {
			MysqlStatement tablesStmt = connection.prepareStatement("SHOW TABLES");
			ResultSet tables = tablesStmt.executeQuery();
			while (tables.next()) {
				if (tables.getString(1).equals("lecture_x_location")) {
					return; // Table exists, don't do anything
				}
			}
			// Add table
			MysqlStatement tableAddStmt = connection.prepareStatement("CREATE TABLE `lecture_x_location` ("
					+ " `lectureid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,"
					+ " `locationid` int(11) NOT NULL,"
					+ " PRIMARY KEY (`lectureid`,`locationid`), KEY locationid (locationid)"
					+ " ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci");
			tableAddStmt.executeUpdate();
			// Add constraint
			MysqlStatement constraintStmt = connection.prepareStatement("ALTER TABLE `lecture_x_location`"
					+ " ADD FOREIGN KEY ( `lectureid` ) REFERENCES `sat`.`lecture` (`lectureid`)"
					+ " ON DELETE CASCADE ON UPDATE CASCADE");
			constraintStmt.executeUpdate();
			connection.commit();
			LOGGER.info("Updated database: Added lecture-location mapping table");
		} catch (SQLException e) {
			LOGGER.error("Query failed in Updater.addLectureLocationMapTable()", e);
			throw e;
		}
	}

	private static void addLocationPrivateField() throws SQLException {
		try (MysqlConnection connection = Database.getConnection()) {
			MysqlStatement checkStmt = connection.prepareStatement("DESCRIBE lecture");
			ResultSet cols = checkStmt.executeQuery();
			while (cols.next()) {
				if (cols.getString("Field").equals("islocationprivate")) {
					return; // Field exists, don't do anything
				}
			}
			// Add field to table
			MysqlStatement columnAddStmt = connection.prepareStatement("ALTER TABLE lecture"
					+ " ADD islocationprivate TINYINT(1) UNSIGNED NOT NULL DEFAULT 0 AFTER isprivate");
			columnAddStmt.executeUpdate();
			connection.commit();
			LOGGER.info("Updated database: Added is location private field in lecture table");
		} catch (SQLException e) {
			LOGGER.error("Query failed in Updater.addLocationPrivateField()", e);
			throw e;
		}
	}

	private static void addHasUsbAccessField() throws SQLException {
		try (MysqlConnection connection = Database.getConnection()) {
			MysqlStatement checkStmt = connection.prepareStatement("DESCRIBE lecture");
			ResultSet cols = checkStmt.executeQuery();
			while (cols.next()) {
				if (cols.getString("Field").equals("hasusbaccess")) {
					return; // Field exists, don't do anything
				}
			}
			// Add field to table
			MysqlStatement columnAddStmt = connection.prepareStatement("ALTER TABLE lecture"
					+ " ADD hasusbaccess TINYINT(1) UNSIGNED NOT NULL DEFAULT 1 AFTER hasinternetaccess");
			columnAddStmt.executeUpdate();
			connection.commit();
			LOGGER.info("Updated database: Added 'hasusbaccess' private field in lecture table");
		} catch (SQLException e) {
			LOGGER.error("Query failed in Updater.addHasUsbAccessField()", e);
			throw e;
		}
	}

	private static void addLogTable() throws SQLException {
		try (MysqlConnection connection = Database.getConnection()) {
			MysqlStatement tablesStmt = connection.prepareStatement("SHOW TABLES");
			ResultSet tables = tablesStmt.executeQuery();
			while (tables.next()) {
				if (tables.getString(1).equals("actionlog")) {
					return; // Table exists, don't do anything
				}
			}
			// Add table
			MysqlStatement tableAddStmt = connection.prepareStatement("CREATE TABLE `actionlog` ("
					+ " `actionid` int(11) NOT NULL AUTO_INCREMENT,"
					+ " `dateline` bigint(20) NOT NULL,"
					+ " `userid` char(36) CHARACTER SET ascii COLLATE ascii_bin DEFAULT NULL,"
					+ " `targetid` char(36) CHARACTER SET ascii COLLATE ascii_bin DEFAULT NULL,"
					+ " `description` varchar(500) NOT NULL,"
					+ " PRIMARY KEY (`actionid`),"
					+ " KEY userid (userid, dateline),"
					+ " KEY targetid (targetid, dateline),"
					+ " KEY dateline (dateline)"
					+ " ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci");
			tableAddStmt.executeUpdate();
			// Add constraint
			MysqlStatement constraintStmt = connection.prepareStatement("ALTER TABLE `actionlog`"
					+ " ADD FOREIGN KEY ( `userid` ) REFERENCES `sat`.`user` (`userid`)"
					+ " ON DELETE SET NULL ON UPDATE CASCADE");
			constraintStmt.executeUpdate();
			connection.commit();
			LOGGER.info("Updated database: Added actionlog table");
		} catch (SQLException e) {
			LOGGER.error("Query failed in Updater.addLogTable()", e);
			throw e;
		}
	}

	/**
	 * Make email field longer. Was 50 chars, which is not enough in rare cases
	 * :)
	 */
	private static void fixEmailFieldLength() throws SQLException {
		try (MysqlConnection connection = Database.getConnection()) {
			MysqlStatement checkStmt = connection.prepareStatement("DESCRIBE user");
			ResultSet cols = checkStmt.executeQuery();
			while (cols.next()) {
				if (cols.getString("Field").equals("email")
						&& "varchar(100)".equalsIgnoreCase(cols.getString("Type"))) {
					return; // Field exists and has proper type, don't do anything
				}
			}
			MysqlStatement upStmt = connection.prepareStatement("ALTER TABLE user CHANGE email"
					+ " email VARCHAR(100) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL");
			upStmt.executeUpdate();
			connection.commit();
			LOGGER.info("Updated database: Made email field longer");
		} catch (SQLException e) {
			LOGGER.error("Query failed in Updater.fixEmailFieldLength()", e);
			throw e;
		}
	}

	private static void addNetworkShares() throws SQLException {
		try (MysqlConnection connection = Database.getConnection()) {
			MysqlStatement tablesStmt = connection.prepareStatement("SHOW TABLES");
			ResultSet tables = tablesStmt.executeQuery();
			while (tables.next()) {
				if (tables.getString(1).equals("networkshare")) {
					return; // Table exists, don't do anything
				}
			}
			// Add table
			MysqlStatement tableAddStmt = connection.prepareStatement(
					"CREATE TABLE `networkshare` ("
					+ " `shareid` int(11) NOT NULL AUTO_INCREMENT,"
					+ " `lectureid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,"
					+ " `shareuid` char(36) CHARACTER SET ascii COLLATE ascii_bin DEFAULT NULL,"
					+ " `sharedata` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL,"
					+ " PRIMARY KEY (`shareid`),"
					+ " KEY `fk_lectureid_1` (`lectureid`)"
					+ ") ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci");
			tableAddStmt.executeUpdate();
			// Add constraint
			MysqlStatement constraintStmt = connection.prepareStatement(
					"ALTER TABLE `networkshare` ADD CONSTRAINT `fk_lectureid_1`"
					+ " FOREIGN KEY (`lectureid`) REFERENCES `sat`.`lecture` (`lectureid`)"
					+ " ON DELETE CASCADE ON UPDATE CASCADE");
			constraintStmt.executeUpdate();
			connection.commit();
			LOGGER.info("Updated database: Added networkshare table");
		} catch (SQLException e) {
			LOGGER.error("Query failed in Updater.addNetworkShares()", e);
			throw e;
		}
	}

	private static void addLectureFilter() throws SQLException {
		try (MysqlConnection connection = Database.getConnection()) {
			MysqlStatement tablesStmt = connection.prepareStatement("SHOW TABLES");
			ResultSet tables = tablesStmt.executeQuery();
			while (tables.next()) {
				if (tables.getString(1).equals("lecturefilter")) {
					return; // Table exists, don't do anything
				}
			}
			// Add table
			MysqlStatement tableAddStmt = connection.prepareStatement(
					"CREATE TABLE `lecturefilter` ("
					+ "  `lectureid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,"
					+ "  `filtertype` varchar(24) CHARACTER SET ascii NOT NULL,"
					+ "  `filterkey` varchar(24) COLLATE utf8mb4_unicode_ci NOT NULL,"
					+ "  `filtervalue` varchar(200) COLLATE utf8mb4_unicode_ci NOT NULL,"
					+ "  KEY `lectureid` (`lectureid`,`filtertype`)"
					+ ") ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci");
			tableAddStmt.executeUpdate();
			// Add constraint
			MysqlStatement constraintStmt = connection.prepareStatement(
					"ALTER TABLE `lecturefilter` ADD "
					+ " CONSTRAINT `lectureid` FOREIGN KEY (`lectureid`) REFERENCES `lecture` (`lectureid`)"
					+ " ON DELETE CASCADE ON UPDATE CASCADE");
			constraintStmt.executeUpdate();
			connection.commit();
			LOGGER.info("Updated database: Added lecture filter table");
		} catch (SQLException e) {
			LOGGER.error("Query failed in Updater.addLectureFilter()", e);
			throw e;
		}
	}

}