/[projects]/android/TrainInfoService/src/dk/thoerup/traininfoservice/db/StationDAO.java
ViewVC logotype

Contents of /android/TrainInfoService/src/dk/thoerup/traininfoservice/db/StationDAO.java

Parent Directory Parent Directory | Revision Log Revision Log


Revision 1516 - (show annotations) (download)
Fri Jun 10 15:05:24 2011 UTC (12 years, 11 months ago) by torben
File size: 10659 byte(s)
remove station suffixes from search string before db lookup
1 package dk.thoerup.traininfoservice.db;
2
3 import java.sql.Array;
4 import java.sql.Connection;
5 import java.sql.PreparedStatement;
6 import java.sql.ResultSet;
7 import java.sql.SQLException;
8 import java.sql.Statement;
9 import java.util.logging.Logger;
10
11 import dk.thoerup.android.traininfo.common.StationBean;
12 import dk.thoerup.android.traininfo.common.StationEntry;
13
14 public class StationDAO {
15
16 private interface StatementParamSetter {
17 public void setParams(PreparedStatement stmt) throws SQLException ;
18 }
19 private class NullSetter implements StatementParamSetter {
20 @Override
21 public void setParams(PreparedStatement stmt) throws SQLException {}
22 }
23
24 public static class NostationException extends Exception {
25 private static final long serialVersionUID = 1L;
26 }
27
28 final static int LOCATION_LIMIT = 8;
29 static final Logger logger = Logger.getLogger(StationDAO.class.getName());
30
31
32 private StationEntry convertSingleRow(ResultSet res) throws SQLException {
33 StationEntry station = new StationEntry();
34
35 station.setId( res.getInt(1) );
36 station.setName( res.getString(2) );
37 station.setLatitude( res.getDouble(3) );
38 station.setLongitude( res.getDouble(4) );
39 station.setRegional( res.getString(5) );
40 station.setStrain( res.getString(6) );
41 station.setMetro( res.getString(7) );
42 station.setAddress( res.getString(8) );
43 station.setCalcdist( (int)res.getDouble(9) );
44
45 station.setIsRegional( station.getRegional() != null );
46 station.setIsStrain( station.getStrain() != null );
47 station.setIsMetro( station.getMetro() != null );
48
49 return station;
50 }
51
52 private StationBean convertResultset(ResultSet res) throws SQLException {
53 StationBean stations = new StationBean();
54 while (res.next()) {
55 stations.entries.add( convertSingleRow(res) );
56 }
57 return stations;
58
59 }
60
61 private StationBean fetchStations(String SQL, StatementParamSetter setter) throws SQLException {
62 StationBean stations;
63 Connection conn = null;
64 PreparedStatement stmt = null;
65 ResultSet res = null;
66 try {
67 conn = DBConnection.getConnection();
68 stmt = conn.prepareStatement(SQL);
69
70 setter.setParams(stmt);
71
72 res = stmt.executeQuery();
73 stations = convertResultset(res);
74
75 } finally {
76 if (res != null)
77 res.close();
78 if (stmt != null)
79 stmt.close();
80 if (conn!= null)
81 conn.close();
82 }
83 return stations;
84
85 }
86
87 public StationEntry getById(int id) throws SQLException,NostationException {
88 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog,stationcode_metro,address,0.0 " +
89 "FROM trainstations WHERE id=" + id + " AND enabled=true";
90
91 StationBean stations = fetchStations(SQL, new NullSetter() );
92
93 if (stations.entries.size() > 0 ) {
94 return stations.entries.get(0);
95 } else {
96 throw new NostationException();
97 }
98 }
99
100
101
102 /*
103 * this code requires theses statements are run on database in order to do ILIKE searches against aliases (which is defines as array of varchar(64) )
104 * create function rlike(text,text) returns bool as
105 * 'select $2 ilike $1' language sql strict immutable;
106 * create operator ~~~ (procedure = rlike, leftarg = text, rightarg = text, commutator = ~~);
107 */
108 public StationBean getByNameNormal(final String name) throws SQLException {
109 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog, stationcode_metro, address, 0.0 " +
110 "FROM trainstations " +
111 "WHERE (name ILIKE ? OR ? ~~~ ANY(aliases)) AND enabled = true " +
112 "ORDER BY name ";
113
114 class NameSetter implements StatementParamSetter {
115 @Override
116 public void setParams(PreparedStatement stmt) throws SQLException {
117 stmt.setString(1, name + "%");
118 stmt.setString(2, name + "%");
119 }
120 }
121
122 return fetchStations(SQL, new NameSetter() );
123 }
124
125
126 public StationBean getByNameFuzzy(final String name) throws SQLException {
127 String SQL = "SELECT * FROM (" +
128 " SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog, stationcode_metro, address, 0.0, " +
129 " levenshtein(lower(name),lower(?) ) as leven " +
130 " FROM trainstations " +
131 " WHERE enabled = true ) as lev2 " +
132 "WHERE (leven <= 3) " +
133 "ORDER BY leven " +
134 "LIMIT 1";
135
136 class NameSetter implements StatementParamSetter {
137 @Override
138 public void setParams(PreparedStatement stmt) throws SQLException {
139 stmt.setString(1, name );
140 }
141 }
142
143 StationBean stations = fetchStations(SQL, new NameSetter() );
144 stations.fuzzystrmatch = true;
145 return stations;
146 }
147
148 private String removeSuffix(String str, String suffix) {
149 if (str.endsWith(suffix)) {
150 return str.substring(0, str.length() - suffix.length() );
151 } else {
152 return str;
153 }
154 }
155
156 public StationBean getByName(String name) throws SQLException {
157 name = removeSuffix(name, " st.");
158 name = removeSuffix(name, " st");
159 name = removeSuffix(name, " station");
160
161 StationBean stations = getByNameNormal(name);
162
163 if (stations.entries.size() == 0) {
164 stations = getByNameFuzzy(name);
165
166 logger.info("getByName failover: " + name + "(" + (stations.entries.size() >0) + ")" );
167 }
168 return stations;
169 }
170
171
172
173 //Latitude (horizonal), longitude(vertical) so
174 // 1 degree latitude is ~ 111320 meters, since the distance between the horizonal lines is always the same
175 // 1 degree longitude is ~111320 meters at equator but gets shorter as we get closer to the poles.
176 // so 1 degree longitude is 64.5 km at denmarks southern point (gedser=54.55,11.95)
177 // and is 59.4km at northern point (skagen = 57.75,10.65)
178 // The "hack" with max 0.4 degrees latitude and 0.75 degrees longitude is only valid since we only service danish trains,
179 // in denmark 0.4dg latitude ~ 44km, 0.75dg longitude ~ 47km
180
181 // the ultra fast method (and only slightly inaccurate as long as we only cover a limited geographically area)
182 // is using an aproximation of the length of 1 latitude degree and 1 longitude degree and just use pythagoras to
183 // calculate the distance:
184 // sqrt( power(abs(latitude-?)*111320, 2) + power(abs(longitude-?)*63000,2) )::int as calcdist
185
186 public StationBean getByLocationWorker(final double latitude, final double longitude, final boolean geolimit) throws SQLException {
187
188 String limitExpression = (geolimit == true) ? "AND abs(latitude-?)<0.4 AND abs(longitude-?)<0.75 " : "";
189
190 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog, stationcode_metro, address, " +
191 "earth_distance( earth_coord, ll_to_earth(?,?))::int AS calcdist " +
192 "FROM trainstations " +
193 "WHERE enabled = true " + limitExpression +
194 "ORDER BY calcdist ASC " +
195 "LIMIT " + LOCATION_LIMIT;
196
197
198 class LatlongSetter implements StatementParamSetter {
199 @Override
200 public void setParams(PreparedStatement stmt) throws SQLException {
201 stmt.setDouble(1, latitude);
202 stmt.setDouble(2, longitude);
203 if (geolimit == true) {
204 stmt.setDouble(3, latitude);
205 stmt.setDouble(4, longitude);
206 }
207 }
208 }
209
210 return fetchStations(SQL, new LatlongSetter() );
211 }
212
213 public StationBean getByLocation(double latitude, double longitude) throws SQLException {
214 StationBean result = getByLocationWorker(latitude, longitude, true);
215
216 if (result.entries.size() < LOCATION_LIMIT) { //failover
217 logger.info("getByLocation failover: " +latitude + "," + longitude);
218
219 result = getByLocationWorker(latitude, longitude, false);
220 }
221
222 return result;
223 }
224
225
226
227 public StationBean getByList(String list) throws SQLException {
228 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog,stationcode_metro, address,0.0 " +
229 "FROM trainstations " +
230 "WHERE id IN " + list + " AND enabled = true " +
231 "ORDER BY name ";
232
233 return fetchStations(SQL, new NullSetter() );
234 }
235
236
237
238 public StationEntry getSimpleByName(final String name) throws SQLException {
239 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog, stationcode_metro, address, 0.0 " +
240 "FROM trainstations " +
241 "WHERE name = ? AND enabled = true " +
242 "LIMIT 1 ";
243
244 class NameSetter implements StatementParamSetter {
245 @Override
246 public void setParams(PreparedStatement stmt) throws SQLException {
247 stmt.setString(1, name );
248 }
249 }
250
251 StationBean stations = fetchStations(SQL, new NameSetter() );
252
253 if (stations.entries.size() == 1) {
254 return stations.entries.get(0);
255 } else {
256 return null;
257 }
258 }
259
260 //used to create full dump in order to populate Google Appengine DB
261 @Deprecated
262 public StationBean dumpAll() throws SQLException {
263
264 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog,stationcode_metro,address,0.0,aliases " +
265 "FROM trainstations WHERE enabled = true ORDER BY id";
266
267 Connection conn = null;
268 Statement stmt = null;
269 ResultSet res = null;
270
271
272 try {
273 conn = DBConnection.getConnection();
274
275 stmt = conn.createStatement();
276 res = stmt.executeQuery(SQL);
277
278 // Does mostly the same as convertResultset()
279 StationBean stations = new StationBean();
280 while (res.next()) {
281 StationEntry entry = convertSingleRow(res);
282
283 Array arr = res.getArray(10);
284 if (arr != null) {
285 String[] aliases = (String[]) arr.getArray();
286 entry.setAliases(aliases);
287 }
288
289 stations.entries.add( entry );
290
291 }
292 return stations;
293
294
295 } finally {
296 if (res != null)
297 res.close();
298 if (stmt != null)
299 stmt.close();
300 if (conn != null)
301 conn.close();
302 }
303
304 }
305
306 @Deprecated
307 public static String getStationName(int stationID) {
308 String station = "";
309
310 Connection conn = null;
311 try {
312 conn = DBConnection.getConnection();
313 Statement stmt = conn.createStatement();
314 ResultSet rs = stmt.executeQuery("SELECT name FROM trainstations WHERE id=" + stationID);
315 if (rs.next()) {
316 station = rs.getString(1);
317 }
318
319 } catch (Exception e) {
320 } finally {
321 try {
322 if (conn != null && !conn.isClosed())
323 conn.close();
324 } catch (Exception e) {}
325 }
326
327 return station;
328 }
329
330
331
332 @Deprecated
333 public int getIdByName(final String name) throws SQLException {
334 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog, stationcode_metro, address, 0.0 " +
335 "FROM trainstations " +
336 "WHERE name = ? AND enabled = true " +
337 "LIMIT 1 ";
338
339 class NameSetter implements StatementParamSetter {
340 @Override
341 public void setParams(PreparedStatement stmt) throws SQLException {
342 stmt.setString(1, name );
343 }
344 }
345
346 StationBean stations = fetchStations(SQL, new NameSetter() );
347
348 if (stations.entries.size() == 1) {
349 return stations.entries.get(0).getId();
350 } else {
351 return -1;
352 }
353 }
354 }

  ViewVC Help
Powered by ViewVC 1.1.20