/[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 1507 - (show annotations) (download)
Wed Jun 8 16:11:27 2011 UTC (12 years, 11 months ago) by torben
File size: 10174 byte(s)
add fuzzy string match in getByName searches
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 id,name,latitude,longitude,stationcode_fjrn,stationcode_stog, stationcode_metro, address, 0.0, " +
128 "levenshtein(lower(name),lower(?) ) as leven " +
129 "FROM trainstations " +
130 "WHERE (levenshtein(lower(name),lower(?) ) <= 3) AND enabled = true " +
131 "AND enabled = true " +
132 "ORDER BY leven " +
133 "LIMIT 1";
134
135 class NameSetter implements StatementParamSetter {
136 @Override
137 public void setParams(PreparedStatement stmt) throws SQLException {
138 stmt.setString(1, name );
139 stmt.setString(2, name );
140 }
141 }
142
143 StationBean stations = fetchStations(SQL, new NameSetter() );
144 stations.fuzzystrmatch = true;
145 return stations;
146 }
147
148 public StationBean getByName(final String name) throws SQLException {
149 StationBean stations = getByNameNormal(name);
150
151 if (stations.entries.size() == 0) {
152 logger.info("getByName failover: " + name);
153 stations = getByNameFuzzy(name);
154 }
155 return stations;
156 }
157
158
159
160 //Latitude (horizonal), longitude(vertical) so
161 // 1 degree latitude is ~ 111320 meters, since the distance between the horizonal lines is always the same
162 // 1 degree longitude is ~111320 meters at equator but gets shorter as we get closer to the poles.
163 // the "hack" with max 0.4 degrees latitude and 0.75 degrees longitude is only valid since we only service danish trains,
164 // in denmark 0.4dg latitude ~ 44km, 0.75dg longitude ~ 47km
165
166 // the ultra fast method (and only slightly inaccurate as long as we only cover a limited geographically area)
167 // is using an aproximation of the length of 1 latitude degree and 1 longitude degree and just use pythagoras to
168 // calculate the distance:
169 // sqrt( power(abs(latitude-?)*111320, 2) + power(abs(longitude-?)*63000,2) )::int as calcdist
170
171 public StationBean getByLocationWorker(final double latitude, final double longitude, final boolean geolimit) throws SQLException {
172
173 String limitExpression = (geolimit == true) ? "AND abs(latitude-?)<0.4 AND abs(longitude-?)<0.75 " : "";
174
175 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog, stationcode_metro, address, " +
176 "earth_distance( earth_coord, ll_to_earth(?,?))::int AS calcdist " +
177 "FROM trainstations " +
178 "WHERE enabled = true " + limitExpression +
179 "ORDER BY calcdist ASC " +
180 "LIMIT " + LOCATION_LIMIT;
181
182
183 class LatlongSetter implements StatementParamSetter {
184 @Override
185 public void setParams(PreparedStatement stmt) throws SQLException {
186 stmt.setDouble(1, latitude);
187 stmt.setDouble(2, longitude);
188 if (geolimit == true) {
189 stmt.setDouble(3, latitude);
190 stmt.setDouble(4, longitude);
191 }
192 }
193 }
194
195 return fetchStations(SQL, new LatlongSetter() );
196 }
197
198 public StationBean getByLocation(double latitude, double longitude) throws SQLException {
199 StationBean result = getByLocationWorker(latitude, longitude, true);
200
201 if (result.entries.size() < LOCATION_LIMIT) { //failover
202 logger.info("getByLocation failover: " +latitude + "," + longitude);
203
204 result = getByLocationWorker(latitude, longitude, false);
205 }
206
207 return result;
208 }
209
210
211
212 public StationBean getByList(String list) throws SQLException {
213 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog,stationcode_metro, address,0.0 " +
214 "FROM trainstations " +
215 "WHERE id IN " + list + " AND enabled = true " +
216 "ORDER BY name ";
217
218 return fetchStations(SQL, new NullSetter() );
219 }
220
221
222
223 public StationEntry getSimpleByName(final String name) throws SQLException {
224 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog, stationcode_metro, address, 0.0 " +
225 "FROM trainstations " +
226 "WHERE name = ? AND enabled = true " +
227 "LIMIT 1 ";
228
229 class NameSetter implements StatementParamSetter {
230 @Override
231 public void setParams(PreparedStatement stmt) throws SQLException {
232 stmt.setString(1, name );
233 }
234 }
235
236 StationBean stations = fetchStations(SQL, new NameSetter() );
237
238 if (stations.entries.size() == 1) {
239 return stations.entries.get(0);
240 } else {
241 return null;
242 }
243 }
244
245 //used to create full dump in order to populate Google Appengine DB
246 @Deprecated
247 public StationBean dumpAll() throws SQLException {
248
249 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog,stationcode_metro,address,0.0,aliases " +
250 "FROM trainstations WHERE enabled = true ORDER BY id";
251
252 Connection conn = null;
253 Statement stmt = null;
254 ResultSet res = null;
255
256
257 try {
258 conn = DBConnection.getConnection();
259
260 stmt = conn.createStatement();
261 res = stmt.executeQuery(SQL);
262
263 // Does mostly the same as convertResultset()
264 StationBean stations = new StationBean();
265 while (res.next()) {
266 StationEntry entry = convertSingleRow(res);
267
268 Array arr = res.getArray(10);
269 if (arr != null) {
270 String[] aliases = (String[]) arr.getArray();
271 entry.setAliases(aliases);
272 }
273
274 stations.entries.add( entry );
275
276 }
277 return stations;
278
279
280 } finally {
281 if (res != null)
282 res.close();
283 if (stmt != null)
284 stmt.close();
285 if (conn != null)
286 conn.close();
287 }
288
289 }
290
291 @Deprecated
292 public static String getStationName(int stationID) {
293 String station = "";
294
295 Connection conn = null;
296 try {
297 conn = DBConnection.getConnection();
298 Statement stmt = conn.createStatement();
299 ResultSet rs = stmt.executeQuery("SELECT name FROM trainstations WHERE id=" + stationID);
300 if (rs.next()) {
301 station = rs.getString(1);
302 }
303
304 } catch (Exception e) {
305 } finally {
306 try {
307 if (conn != null && !conn.isClosed())
308 conn.close();
309 } catch (Exception e) {}
310 }
311
312 return station;
313 }
314
315
316
317 @Deprecated
318 public int getIdByName(final String name) throws SQLException {
319 String SQL = "SELECT id,name,latitude,longitude,stationcode_fjrn,stationcode_stog, stationcode_metro, address, 0.0 " +
320 "FROM trainstations " +
321 "WHERE name = ? AND enabled = true " +
322 "LIMIT 1 ";
323
324 class NameSetter implements StatementParamSetter {
325 @Override
326 public void setParams(PreparedStatement stmt) throws SQLException {
327 stmt.setString(1, name );
328 }
329 }
330
331 StationBean stations = fetchStations(SQL, new NameSetter() );
332
333 if (stations.entries.size() == 1) {
334 return stations.entries.get(0).getId();
335 } else {
336 return -1;
337 }
338 }
339 }

  ViewVC Help
Powered by ViewVC 1.1.20