Project

General

Profile

1
package eu.dnetlib.enabling.database.utils;
2

    
3
import java.io.StringReader;
4
import java.sql.*;
5
import java.sql.Date;
6
import java.text.ParseException;
7
import java.text.SimpleDateFormat;
8
import java.util.*;
9
import java.util.concurrent.ArrayBlockingQueue;
10
import java.util.concurrent.BlockingQueue;
11
import java.util.concurrent.Executors;
12
import java.util.concurrent.TimeUnit;
13
import java.util.concurrent.atomic.AtomicReference;
14
import java.util.regex.Pattern;
15
import javax.sql.DataSource;
16

    
17
import com.google.common.collect.Lists;
18
import com.google.common.collect.Queues;
19
import com.google.common.collect.Sets;
20
import eu.dnetlib.enabling.database.DataSourceFactory;
21
import eu.dnetlib.enabling.database.TransactionTemplateFactory;
22
import eu.dnetlib.enabling.database.objects.DnetDatabase;
23
import eu.dnetlib.enabling.database.rmi.DatabaseException;
24
import eu.dnetlib.miscutils.datetime.DateUtils;
25
import eu.dnetlib.miscutils.functional.string.Sanitizer;
26
import org.apache.commons.dbcp2.BasicDataSource;
27
import org.apache.commons.lang.BooleanUtils;
28
import org.apache.commons.logging.Log;
29
import org.apache.commons.logging.LogFactory;
30
import org.apache.velocity.app.VelocityEngine;
31
import org.dom4j.Document;
32
import org.dom4j.DocumentHelper;
33
import org.dom4j.Element;
34
import org.dom4j.Node;
35
import org.dom4j.io.SAXReader;
36
import org.joda.time.DateTime;
37
import org.joda.time.format.ISODateTimeFormat;
38
import org.springframework.beans.factory.annotation.Required;
39
import org.springframework.dao.DataAccessException;
40
import org.springframework.jdbc.core.JdbcTemplate;
41
import org.springframework.jdbc.support.rowset.SqlRowSet;
42
import org.springframework.transaction.support.TransactionTemplate;
43
import org.springframework.ui.velocity.VelocityEngineUtils;
44

    
45
public class DatabaseUtils {
46

    
47
	public static final String DNET_RESOURCE_ID_FIELD = "_dnet_resource_identifier_";
48
	public static final int BLOCKING_QUEUE_TIMEOUT = 300;
49
	private static final String SQL_DATE_FORMAT = "yyyy-MM-dd";
50
	private static final Log log = LogFactory.getLog(DatabaseUtils.class); // NOPMD by marko on 11/24/08 5:02 PM
51
	private static final int BLOCKING_QUEUE_SIZE = 200;
52
	private static final Set<String> TRUE_VALUES = Sets.newHashSet("true", "t", "yes", "y", "vero", "v");
53
	private static final Set<String> FALSE_VALUES = Sets.newHashSet("false", "f", "no", "n", "falso");
54
	private DataSourceFactory dataSourceFactory;
55
	private JdbcTemplateFactory jdbcTemplateFactory;
56
	private TransactionTemplateFactory transactionTemplateFactory;
57
	private String defaultDB;
58
	private VelocityEngine velocityEngine;
59
	private String dbPrefix;
60
	private int numbersOfRecordsForTransaction;
61
	private int fetchSize = 100;
62

    
63
	public List<String> listCommonDBTables(final String database) throws DatabaseException {
64
		String query =
65
				"SELECT table_name FROM information_schema.tables " + "WHERE table_schema = 'public' " + "AND table_type != 'VIEW' "
66
						+ "AND table_name NOT LIKE '%_log'";
67
		return getTypedListFromSql(database, query, String.class);
68
	}
69

    
70
	public List<String> listCommonDBViews(final String database) throws DatabaseException {
71
		String query =
72
				"SELECT table_name FROM information_schema.tables " + "WHERE table_schema = 'public' " + "AND table_type = 'VIEW' "
73
						+ "AND table_name NOT LIKE '%_log'";
74
		return getTypedListFromSql(database, query, String.class);
75
	}
76

    
77
	public Map<String, TableDates> getTableDatesForDB(final String db) throws DatabaseException {
78
		Map<String, TableDates> res = new HashMap<String, TableDates>();
79

    
80
		for (String table : listCommonDBTables(db)) {
81
			try {
82
				TableDates dates = new TableDates();
83

    
84
				String query =
85
						"select lastinsert, lastupdate, lastdelete from " + "(select max(date) as lastinsert from " + table
86
								+ "_log where operation='insert') as t1, " + "(select max(date) as lastupdate from " + table
87
								+ "_log where operation='update') as t2, " + "(select max(date) as lastdelete from " + table
88
								+ "_log where operation='delete') as t3";
89

    
90
				SqlRowSet srs = executeSql(db, query, SqlRowSet.class);
91
				if (srs.next()) {
92
					dates.setLastInsert(srs.getDate("lastinsert"));
93
					dates.setLastUpdate(srs.getDate("lastupdate"));
94
					dates.setLastDelete(srs.getDate("lastdelete"));
95
				}
96
				res.put(table, dates);
97
			} catch (Exception e) {
98
				log.warn("Error obtaing dates for table " + table, e);
99
			}
100
		}
101
		return res;
102
	}
103

    
104
	public List<DnetDatabase> listAllDatabases() throws DatabaseException {
105
		final String query =
106
				"SELECT d.datname AS db, COALESCE(dsc.description,'')='isManaged' AS managed FROM pg_database d LEFT OUTER JOIN pg_shdescription dsc ON (d.oid = dsc.objoid) WHERE d.datname LIKE '"
107
						+ dbPrefix + "%' ORDER BY d.datname DESC";
108
		final JdbcTemplate jdbcTemplate = getJdbcTemplate(defaultDB);
109

    
110
		final List<DnetDatabase> list = Lists.newArrayList();
111
		for (Map<String, Object> map : jdbcTemplate.queryForList(query)) {
112
			list.add(new DnetDatabase(map.get("db").toString(), Boolean.parseBoolean(map.get("managed").toString())));
113
		}
114
		return list;
115

    
116
	}
117

    
118
	public <T> List<T> getTypedListFromSql(final String dbName, final String query, final Class<T> clazz) throws DatabaseException {
119
		try {
120
			List<T> list = new ArrayList<T>();
121
			for (Object obj : getJdbcTemplate(dbName).queryForList(query, clazz)) {
122
				list.add(clazz.cast(obj));
123
			}
124
			return list;
125
		} catch (DataAccessException e) {
126
			throw new DatabaseException(e);
127
		}
128
	}
129

    
130
	public List<String> getSimpleListFromSql(final String dbName, final String query) throws DatabaseException {
131

    
132
		JdbcTemplate jdbcTemplate = getJdbcTemplate(dbName);
133

    
134
		try {
135
			List<String> list = new ArrayList<>();
136
			for (Object obj : jdbcTemplate.queryForList(query)) {
137
				list.add(obj.toString());
138
			}
139
			return list;
140
		} catch (DataAccessException e) {
141
			throw new DatabaseException(e);
142
		}
143
	}
144

    
145
	public void executeSql(final String db, final String query) throws DatabaseException {
146
		executeSql(db, query, Void.class);
147
	}
148

    
149
	@SuppressWarnings("unchecked")
150
	public <T> T executeSql(final String dbName, final String query, final Class<T> clazz) throws DatabaseException {
151

    
152
		if (clazz == BlockingQueue.class) {
153
			log.debug("Creating Queue");
154

    
155
			final ArrayBlockingQueue<Map<String, Object>> queue = Queues.newArrayBlockingQueue(BLOCKING_QUEUE_SIZE);
156
			Executors.newSingleThreadExecutor().submit(() -> {
157

    
158
				try (final Connection con = getJdbcTemplate(dbName).getDataSource().getConnection();
159
						final PreparedStatement stm = getStm(query, con);
160
						final ResultSet rs = stm.executeQuery()) {
161
					con.setAutoCommit(false);
162
					rs.setFetchSize(getFetchSize());
163
					boolean timeout = false;
164
					log.info(String.format("starting to populate queue T-id %s", Thread.currentThread().getId()));
165
					while (rs.next()) {
166
						ResultSetMetaData md = rs.getMetaData();
167
						Map<String, Object> row = new HashMap<>();
168
						for (int i = 1; i <= md.getColumnCount(); i++) {
169
							row.put(md.getColumnName(i), rs.getObject(i));
170
						}
171
						if (!enqueue(queue, row)) {
172
							timeout = true;
173
							break;
174
						}
175
					}
176
					if (timeout) {
177
						throw new RuntimeException(String.format("queue full, consumer did not consume for %s seconds", BLOCKING_QUEUE_TIMEOUT));
178
					}
179
					// An empty Map indicates the end of the resultset
180
					enqueue(queue, new HashMap<>());
181
				} catch (SQLException e) {
182
					throw new RuntimeException(e);
183
				}
184
			});
185

    
186
			log.debug("Returned Queue");
187

    
188
			return (T) queue;
189
		}
190

    
191
		try(BasicDataSource ds = (BasicDataSource) dataSourceFactory.createDataSource(dbName)) {
192
			final JdbcTemplate jdbcTemplate = jdbcTemplateFactory.createJdbcTemplate(ds);
193
			if (clazz == Integer.class) return (T) jdbcTemplate.queryForObject(query, Integer.class);
194
			else if (clazz == List.class) return (T) jdbcTemplate.queryForList(query);
195
			else if (clazz == Map.class) return (T) jdbcTemplate.queryForMap(query);
196
			else if (clazz == SqlRowSet.class) return (T) jdbcTemplate.queryForRowSet(query);
197
			else {
198
				jdbcTemplate.update(query);
199
				return null;
200
			}
201
		} catch (SQLException e) {
202
			throw new DatabaseException(e);
203
		}
204
	}
205

    
206
	private boolean enqueue(final ArrayBlockingQueue<Map<String, Object>> q, final Map<String, Object> row) {
207
		try {
208
			return q.offer(row, BLOCKING_QUEUE_TIMEOUT, TimeUnit.SECONDS);
209
		} catch (InterruptedException e) {
210
			log.error("Error putting element in queue");
211
			throw new RuntimeException(e);
212
		}
213
	}
214

    
215
	private PreparedStatement getStm(final String query, final Connection con) throws SQLException {
216
		final PreparedStatement stm = con.prepareStatement(query, ResultSet.TYPE_FORWARD_ONLY);
217
		stm.setFetchSize(getFetchSize());
218
		return stm;
219
	}
220

    
221
	public boolean contains(final String db, final String table, final String column, final String value) throws DatabaseException {
222
		String query = "";
223
		try {
224
			verifyParameters(db, table, column);
225
			query = "SELECT " + column + " FROM " + table + " WHERE " + column + " = '" + value + "'";
226
			List<String> res = getSimpleListFromSql(db, query);
227
			return res != null && res.size() > 0;
228
		} catch (Throwable e) {
229
			throw new DatabaseException("Error performing SQL: " + query, e);
230
		}
231
	}
232

    
233
	public List<Map<?, ?>> describeTable(final String database, final String table) throws DatabaseException {
234
		verifyParameters(database, table);
235

    
236
		try {
237
			final JdbcTemplate jdbcTemplate = getJdbcTemplate(database);
238
			List<Map<?, ?>> response = new ArrayList<Map<?, ?>>();
239
			String query = "SELECT * FROM information_schema.columns WHERE table_name = ?";
240

    
241
			for (Object o : jdbcTemplate.queryForList(query, new Object[] { table })) {
242
				if (o instanceof Map<?, ?>) {
243
					response.add((Map<?, ?>) o);
244
				}
245
			}
246
			return response;
247
		} catch (DataAccessException e) {
248
			throw new DatabaseException(e);
249
		}
250
	}
251

    
252
	public String dumpTableAsXML(final String db, final String t) throws DatabaseException {
253
		return dumpTableAsDoc(db, t).asXML();
254
	}
255

    
256
	public Document dumpTableAsDoc(final String db, final String t) throws DatabaseException {
257
		Document doc = DocumentHelper.createDocument();
258

    
259
		Element root = doc.addElement("DB_TABLE");
260
		Element head = root.addElement("HEADER");
261

    
262
		head.addElement("DATABASE").addAttribute("value", db);
263
		head.addElement("TABLE").addAttribute("value", t);
264
		head.addElement("DATE").addAttribute("value", DateUtils.now_ISO8601());
265

    
266
		Element body = root.addElement("BODY");
267
		for (Document d : dumpTableAsList(db, t)) {
268
			body.add(d.getRootElement());
269
		}
270
		return doc;
271
	}
272

    
273
	public List<Document> dumpTableAsList(final String db, final String t) throws DatabaseException {
274
		final JdbcTemplate jdbcTemplate = getJdbcTemplate(db);
275

    
276
		List<Document> list = new ArrayList<Document>();
277
		for (Object o : jdbcTemplate.queryForList("SELECT * FROM " + t)) {
278
			if (o instanceof Map<?, ?>) {
279
				list.add(rowToDocument((Map<?, ?>) o));
280
			}
281
		}
282
		return list;
283
	}
284

    
285
	public Document rowToDocument(final Map<?, ?> map) throws DatabaseException {
286
		Document doc = DocumentHelper.createDocument();
287

    
288
		Element row = doc.addElement("ROW");
289
		for (Map.Entry<?, ?> entry : map.entrySet()) {
290
			Element col = row.addElement("FIELD");
291
			col.addAttribute("name", "" + entry.getKey());
292
			addValue(col, entry.getValue());
293
		}
294
		return doc;
295
	}
296

    
297
	public Document getRowByResourceId(final String database, final String table, final String resourceId) throws DatabaseException {
298
		verifyParameters(database, table);
299

    
300
		JdbcTemplate jdbcTemplate = getJdbcTemplate(database);
301
		String query = "SELECT * FROM " + table + " WHERE " + DNET_RESOURCE_ID_FIELD + "=?";
302

    
303
		Map<?, ?> map = jdbcTemplate.queryForMap(query, resourceId);
304
		Document doc = DocumentHelper.createDocument();
305

    
306
		Element root = doc.addElement("DB_RECORD");
307
		Element head = root.addElement("HEADER");
308
		head.addElement("RESOURCE_IDENTIFIER").addAttribute("value", resourceId);
309
		head.addElement("DATABASE").addAttribute("value", database);
310
		head.addElement("TABLE").addAttribute("value", table);
311
		head.addElement("DATE").addAttribute("value", DateUtils.now_ISO8601());
312

    
313
		Element body = root.addElement("BODY");
314

    
315
		Element row = body.addElement("ROW");
316

    
317
		for (Map.Entry<?, ?> entry : map.entrySet()) {
318
			Element col = row.addElement("FIELD");
319
			col.addAttribute("name", "" + entry.getKey());
320
			addValue(col, entry.getValue());
321
		}
322

    
323
		return doc;
324
	}
325

    
326
	private void addValue(final Element elem, final Object value) throws DatabaseException {
327
		if (value instanceof Array) {
328
			try {
329
				for (Object o : (Object[]) ((Array) value).getArray()) {
330
					addValue(elem.addElement("ITEM"), o);
331
				}
332
			} catch (Exception e) {
333
				throw new DatabaseException("Error procsessing a Array", e);
334
			}
335
		} else if (value != null) {
336
			elem.addText(Sanitizer.sanitize(value.toString()));
337
		} else {
338
			elem.addAttribute("isNull", "true");
339
		}
340
	}
341

    
342
	private void verifyParameters(final String... params) throws DatabaseException {
343
		Pattern pattern = Pattern.compile("\\w{1,128}");
344

    
345
		for (String p : params) {
346
			log.debug("TESTING SQL PARAM:" + p);
347
			if (p == null) throw new DatabaseException("Parameter is null");
348
			else if (!pattern.matcher(p).matches()) throw new DatabaseException("Parameter [" + p + "] contains an invalid character");
349
			else {
350
				log.debug("TEST OK");
351
			}
352
		}
353
	}
354

    
355
	public void importFromIterable(final String db, final Iterable<String> iterable) throws DatabaseException {
356
		verifyParameters(db);
357

    
358
		final DataSource dataSource = dataSourceFactory.createDataSource(db);
359
		final JdbcTemplate jdbcTemplate = getJdbcTemplate(db);
360
		final TransactionTemplate transactionTemplate = transactionTemplateFactory.createTransactionTemplate(dataSource);
361

    
362
		int counterTotal = 0;
363

    
364
		long start = DateUtils.now();
365

    
366
		List<GenericRow> rows = new ArrayList<GenericRow>();
367
		for (String prof : iterable) {
368
			rows.addAll(obtainListOfRows(prof));
369
			if (rows.size() > numbersOfRecordsForTransaction) {
370
				counterTotal += rows.size();
371
				importTransaction(jdbcTemplate, transactionTemplate, rows);
372
				rows.clear();
373
			}
374
		}
375
		counterTotal += rows.size();
376
		importTransaction(jdbcTemplate, transactionTemplate, rows);
377

    
378
		long end = DateUtils.now();
379

    
380
		log.info("**********************************************************");
381
		log.info("Processed " + counterTotal + " rows in " + ((end - start) / 1000) + " seconds");
382
		log.info("**********************************************************");
383
	}
384

    
385
	private void importTransaction(final JdbcTemplate jdbcTemplate, final TransactionTemplate transactionTemplate, List<GenericRow> rows)
386
			throws DatabaseException {
387
		if (rows != null && rows.size() > 0) {
388
			importTransactionInternal(jdbcTemplate, transactionTemplate, rows);
389
		}
390
	}
391

    
392
	private List<GenericRow> importTransactionInternal(final JdbcTemplate jdbcTemplate,
393
			final TransactionTemplate transactionTemplate,
394
			final List<GenericRow> rows) throws DatabaseException {
395

    
396
		final AtomicReference<DatabaseException> error = new AtomicReference<DatabaseException>();
397

    
398
		try {
399
			return transactionTemplate.execute(status -> {
400
				final List<GenericRow> ok = Lists.newArrayList();
401
				try {
402
					for (GenericRow row : rows) {
403
						if (row.isToDelete()) {
404
							deleteRow(jdbcTemplate, row.getTable(), row.getFields());
405
						} else {
406
							addOrUpdateRow(jdbcTemplate, row.getTable(), row.getFields());
407
						}
408
						ok.add(row);
409
					}
410
				} catch (DatabaseException e) {
411
					log.warn("Transaction failed", e);
412
					status.setRollbackOnly();
413
					error.set(e);
414
				}
415
				return ok;
416
			});
417
		} finally {
418
			if (error.get() != null) {
419
				throw error.get();
420
			}
421
		}
422
	}
423

    
424
	protected void addOrUpdateRow(final JdbcTemplate jdbcTemplate, final String table, final Map<String, Object> rowFields) throws DatabaseException {
425
		try {
426

    
427
			if (log.isDebugEnabled()) {
428
				log.debug("Adding or updating element to table " + table);
429
			}
430
			verifyParameters(table);
431
			verifyParameters(rowFields.keySet().toArray(new String[rowFields.size()]));
432

    
433
			String fields = "";
434
			String values = "";
435
			List<Object> list = new ArrayList<Object>();
436

    
437
			for (Map.Entry<String, Object> e : rowFields.entrySet()) {
438
				if (!fields.isEmpty()) {
439
					fields += ",";
440
				}
441
				fields += e.getKey();
442
				if (!values.isEmpty()) {
443
					values += ",";
444
				}
445
				values += "?";
446
				list.add(e.getValue());
447
			}
448

    
449
			int count = 0;
450
			if (rowFields.containsKey(DNET_RESOURCE_ID_FIELD)) {
451
				List<Object> list2 = new ArrayList<Object>();
452
				list2.addAll(list);
453
				list2.add(rowFields.get(DNET_RESOURCE_ID_FIELD));
454
				count =
455
						jdbcTemplate.update("UPDATE " + table + " SET (" + fields + ") = (" + values + ") WHERE " + DNET_RESOURCE_ID_FIELD + "=?",
456
								list2.toArray());
457
			}
458
			if (count == 0) {
459
				jdbcTemplate.update("INSERT INTO " + table + " (" + fields + ") VALUES (" + values + ")", list.toArray());
460
			}
461
		} catch (final Exception e) {
462
			throw new DatabaseException("Error adding or updating record", e);
463
		}
464
	}
465

    
466
	protected void deleteRow(final JdbcTemplate jdbcTemplate, final String table, final Map<String, Object> rowFields) throws DatabaseException {
467
		if (log.isDebugEnabled()) {
468
			log.debug("Deleting element from table " + table);
469
		}
470
		verifyParameters(table);
471
		verifyParameters(rowFields.keySet().toArray(new String[rowFields.size()]));
472

    
473
		List<Object> list = new ArrayList<Object>();
474

    
475
		String where = "";
476

    
477
		for (Map.Entry<String, Object> e : rowFields.entrySet()) {
478
			if (!where.isEmpty()) {
479
				where += " AND ";
480
			}
481
			where += e.getKey() + "=?";
482
			list.add(e.getValue());
483
		}
484

    
485
		if (where.isEmpty()) throw new DatabaseException("Delete condition is empty");
486
		int n = jdbcTemplate.update("DELETE FROM " + table + " WHERE " + where, list.toArray());
487

    
488
		if (log.isDebugEnabled()) {
489
			log.debug("Number of Deleted records: " + n);
490
		}
491
	}
492

    
493
	public void deleteRowByResourceId(final String database, final String table, final String resourceIdentifier) throws DatabaseException {
494
		verifyParameters(database, table, resourceIdentifier);
495
		final JdbcTemplate jdbcTemplate = getJdbcTemplate(database);
496
		jdbcTemplate.update("DELETE FROM " + table + " WHERE " + DNET_RESOURCE_ID_FIELD + "=?", resourceIdentifier);
497
	}
498

    
499
	public void clearTable(final String database, final String table) throws DatabaseException {
500
		verifyParameters(database, table);
501

    
502
		final JdbcTemplate jdbcTemplate = getJdbcTemplate(database);
503
		jdbcTemplate.update("DELETE FROM " + table);
504
	}
505

    
506
	public void prepareManagementOfTable(final String database, final String table) throws DatabaseException {
507
		verifyParameters(database, table);
508
		final JdbcTemplate jdbcTemplate = getJdbcTemplate(database);
509

    
510
		if (!isManagedTable(jdbcTemplate, table)) {
511
			jdbcTemplate.update(getSQLFromTemplate("manageTable", database, table, null));
512
			log.info("Added management of table " + table);
513
		}
514
	}
515

    
516
	public void removeManagementOfTable(final String database, final String table) throws DatabaseException {
517
		verifyParameters(database, table);
518
		final JdbcTemplate jdbcTemplate = getJdbcTemplate(database);
519

    
520
		if (isManagedTable(jdbcTemplate, table)) {
521
			jdbcTemplate.update(getSQLFromTemplate("unmanageTable", database, table, null));
522
			log.info("Removed management of table " + table);
523
		}
524
	}
525

    
526
	public boolean isManagedTable(final String database, final String table) throws DatabaseException {
527
		verifyParameters(database, table);
528
		final JdbcTemplate jdbcTemplate = getJdbcTemplate(database);
529
		return isManagedTable(jdbcTemplate, table);
530
	}
531

    
532
	private boolean isManagedTable(final JdbcTemplate jdbcTemplate, final String table) {
533
		return jdbcTemplate.queryForObject("SELECT count(*) FROM information_schema.columns WHERE table_name = ? AND column_name = ?", Integer.class,
534
				table, DNET_RESOURCE_ID_FIELD) == 1;
535
	}
536

    
537
	public boolean isLoggedTable(final String database, final String table) throws DatabaseException {
538
		verifyParameters(database, table);
539
		final JdbcTemplate jdbcTemplate = getJdbcTemplate(database);
540
		return isLoggedTable(jdbcTemplate, table);
541
	}
542

    
543
	private boolean isLoggedTable(final JdbcTemplate jdbcTemplate, final String table) {
544
		return jdbcTemplate.queryForObject("SELECT count(*) FROM information_schema.tables WHERE table_name = ?", Integer.class,
545
				table + "_log") == 1;
546
	}
547

    
548
	public String getDefaultDnetIdentifier(final String database, final String table) throws DatabaseException {
549
		verifyParameters(database, table);
550
		final JdbcTemplate jdbcTemplate = getJdbcTemplate(database);
551
		if (isManagedTable(jdbcTemplate, table)) return jdbcTemplate.queryForObject(
552
				"SELECT column_default FROM information_schema.columns WHERE table_name = ? AND column_name = ?", new Object[] {
553
						table, DNET_RESOURCE_ID_FIELD }, String.class);
554
		return "";
555
	}
556

    
557
	public void reassignDefaultDnetIdentifiers(final String db) throws DatabaseException {
558
		for (String t : listCommonDBTables(db)) {
559
			reassignDefaultDnetIdentifiers(db, t);
560
		}
561
	}
562

    
563
	public void reassignDefaultDnetIdentifiers(final String db, final String t) throws DatabaseException {
564
		if (!isManagedTable(db, t)) return;
565

    
566
		SqlRowSet rows =
567
				executeSql(db, "SELECT pg_attribute.attname as pkey FROM pg_index, pg_class, pg_attribute " + "WHERE pg_class.oid = '" + t + "'::regclass "
568
						+ "AND indrelid = pg_class.oid " + "AND pg_attribute.attrelid = pg_class.oid "
569
						+ "AND pg_attribute.attnum = any(pg_index.indkey) AND indisprimary " + "ORDER BY pkey", SqlRowSet.class);
570

    
571
		String defaultValue = "";
572
		while (rows.next()) {
573
			if (!defaultValue.isEmpty()) {
574
				defaultValue += "||'@@'||";
575
			}
576
			defaultValue += rows.getString("pkey");
577
		}
578
		executeSql(db, "UPDATE " + t + " SET " + DatabaseUtils.DNET_RESOURCE_ID_FIELD + " = " + defaultValue);
579
		log.info("Reassigned dnetId for table " + t);
580
	}
581

    
582
	public String getSQLFromTemplate(final String sqlTemplate, final String db, final String table, Map<String, Object> map) {
583
		if (map == null) {
584
			map = new HashMap<String, Object>();
585
		}
586

    
587
		map.put("mainDB", defaultDB);
588
		map.put("db", db);
589
		map.put("table", table);
590
		map.put("idField", DNET_RESOURCE_ID_FIELD);
591

    
592
		return VelocityEngineUtils.mergeTemplateIntoString(velocityEngine, "eu/dnetlib/enabling/database/velocity/" + sqlTemplate + ".sql.vm", "UTF-8", map);
593
	}
594

    
595
	public List<GenericRow> obtainListOfRows(final String xml) throws DatabaseException {
596
		try {
597
			Document doc = new SAXReader().read(new StringReader(xml));
598

    
599
			List<GenericRow> list = new ArrayList<GenericRow>();
600

    
601
			for (Object or : doc.selectNodes("//ROW")) {
602
				Element row = (Element) or;
603

    
604
				String table = row.valueOf("@table");
605

    
606
				if ((table == null) || table.isEmpty()) throw new DatabaseException("Attribute table is missing in XSLT");
607

    
608
				boolean toDelete = "deleted".equals(row.valueOf("@status"));
609

    
610
				Map<String, Object> fields = new HashMap<String, Object>();
611

    
612
				for (Object of : row.selectNodes("./FIELD")) {
613
					Node node = (Node) of;
614
					String key = node.valueOf("@name");
615
					String type = node.valueOf("@type");
616
					String format = node.valueOf("@format");
617
					String valueS = node.getText().trim();
618

    
619
					if ((key != null) && !key.isEmpty()) {
620
						Object value = valueS;
621
						if (type != null) {
622

    
623
							try {
624
								// probably an empty string in a typed field means null
625
								if ("".equals(valueS)) {
626
									value = null;
627
								} else if (type.equals("int")) {
628
									value = Integer.parseInt(valueS);
629
								} else if (type.equals("float")) {
630
									value = Float.parseFloat(valueS);
631
								} else if (type.equals("boolean")) {
632
									value = parseBoolean(valueS);
633
								} else if (type.equals("date")) {
634
									value = parseDate(valueS, format);
635
								} else if (type.equals("iso8601Date")) {
636
									DateTime date = ISODateTimeFormat.dateTimeParser().parseDateTime(valueS);
637
									value = date.toDate();
638
									// value = new DateUtils().parse(valueS);
639
								}
640
							} catch (IllegalArgumentException e) {
641
								log.fatal("cannot convert '" + valueS + "' to " + type, e);
642
								throw e;
643
							}
644
						}
645
						fields.put(key, value);
646
					}
647
				}
648

    
649
				list.add(new GenericRow(table, fields, toDelete));
650
			}
651
			return list;
652
		} catch (Exception e) {
653
			log.error("Error obtaining list of rows from xml: " + xml);
654
			throw new DatabaseException(e);
655
		}
656
	}
657

    
658
	protected boolean parseBoolean(final String s) {
659
		if (TRUE_VALUES.contains(s.toLowerCase().trim())) return true;
660
		if (FALSE_VALUES.contains(s.toLowerCase().trim())) return false;
661

    
662
		return BooleanUtils.toBoolean(s);
663
	}
664

    
665
	public void setManaged(final String dbName, final boolean managed) throws DatabaseException {
666
		verifyParameters(dbName);
667
		JdbcTemplate jdbcTemplate = getJdbcTemplate(dbName);
668
		if (managed) {
669
			jdbcTemplate.update("COMMENT ON DATABASE " + dbName + " IS 'isManaged'");
670
		} else {
671
			jdbcTemplate.update("COMMENT ON DATABASE " + dbName + " IS NULL");
672
		}
673
	}
674

    
675
	// public for testing
676
	public Date parseDate(final String date, String format) {
677
		if ((format == null) || format.isEmpty()) {
678
			format = SQL_DATE_FORMAT;
679
		}
680
		try {
681
			java.util.Date parsed = new SimpleDateFormat(format).parse(date);
682
			String ret = new SimpleDateFormat(SQL_DATE_FORMAT).format(parsed);
683
			return Date.valueOf(ret);
684
		} catch (ParseException e) {
685
			return null;
686
		}
687
	}
688

    
689
	private JdbcTemplate getJdbcTemplate(final String dbName) {
690
		JdbcTemplate jdbcTemplate = jdbcTemplateFactory.createJdbcTemplate(dbName);
691
		jdbcTemplate.setFetchSize(getFetchSize());
692
		return jdbcTemplate;
693
	}
694

    
695
	@Required
696
	public void setVelocityEngine(final VelocityEngine velocityEngine) {
697
		this.velocityEngine = velocityEngine;
698
	}
699

    
700
	public String getDbPrefix() {
701
		return dbPrefix;
702
	}
703

    
704
	@Required
705
	public void setDbPrefix(final String dbPrefix) {
706
		this.dbPrefix = dbPrefix;
707
	}
708

    
709
	public DataSourceFactory getDataSourceFactory() {
710
		return dataSourceFactory;
711
	}
712

    
713
	@Required
714
	public void setDataSourceFactory(final DataSourceFactory dataSourceFactory) {
715
		this.dataSourceFactory = dataSourceFactory;
716
	}
717

    
718
	public JdbcTemplateFactory getJdbcTemplateFactory() {
719
		return jdbcTemplateFactory;
720
	}
721

    
722
	@Required
723
	public void setJdbcTemplateFactory(final JdbcTemplateFactory jdbcTemplateFactory) {
724
		this.jdbcTemplateFactory = jdbcTemplateFactory;
725
	}
726

    
727
	public TransactionTemplateFactory getTransactionTemplateFactory() {
728
		return transactionTemplateFactory;
729
	}
730

    
731
	@Required
732
	public void setTransactionTemplateFactory(final TransactionTemplateFactory transactionTemplateFactory) {
733
		this.transactionTemplateFactory = transactionTemplateFactory;
734
	}
735

    
736
	public int getNumbersOfRecordsForTransaction() {
737
		return numbersOfRecordsForTransaction;
738
	}
739

    
740
	@Required
741
	public void setNumbersOfRecordsForTransaction(final int numbersOfRecordsForTransaction) {
742
		this.numbersOfRecordsForTransaction = numbersOfRecordsForTransaction;
743
	}
744

    
745
	public String getDefaultDB() {
746
		return defaultDB;
747
	}
748

    
749
	@Required
750
	public void setDefaultDB(final String defaultDB) {
751
		this.defaultDB = defaultDB;
752
	}
753

    
754
	public int getFetchSize() {
755
		return fetchSize;
756
	}
757

    
758
	public void setFetchSize(final int fetchSize) {
759
		this.fetchSize = fetchSize;
760
	}
761

    
762
	public class TableDates {
763

    
764
		private java.sql.Date lastInsert;
765
		private java.sql.Date lastUpdate;
766
		private java.sql.Date lastDelete;
767

    
768
		public java.sql.Date getLastInsert() {
769
			return lastInsert;
770
		}
771

    
772
		public void setLastInsert(final Date lastInsert) {
773
			this.lastInsert = lastInsert;
774
		}
775

    
776
		public Date getLastUpdate() {
777
			return lastUpdate;
778
		}
779

    
780
		public void setLastUpdate(final Date lastUpdate) {
781
			this.lastUpdate = lastUpdate;
782
		}
783

    
784
		public Date getLastDelete() {
785
			return lastDelete;
786
		}
787

    
788
		public void setLastDelete(final Date lastDelete) {
789
			this.lastDelete = lastDelete;
790
		}
791
	}
792

    
793
}
(1-1/3)