Project

General

Profile

Download (7.93 KB) Statistics
| Branch: | Tag: | Revision:
1
// $Id$
2
/**
3
* Copyright (C) 2009 EDIT
4
* European Distributed Institute of Taxonomy
5
* http://www.e-taxonomy.eu
6
*
7
* The contents of this file are subject to the Mozilla Public License Version 1.1
8
* See LICENSE.TXT at the top of this package for the full license terms.
9
*/
10
package eu.etaxonomy.cdm.database.update;
11

    
12
import java.sql.SQLException;
13

    
14
import org.apache.log4j.Logger;
15

    
16
import eu.etaxonomy.cdm.common.monitor.IProgressMonitor;
17
import eu.etaxonomy.cdm.database.DatabaseTypeEnum;
18
import eu.etaxonomy.cdm.database.ICdmDataSource;
19

    
20
/**
21
 * Dropps a UNIQUE index on a column in a table. If no unique index exists on the column no operation is executed.
22
 *
23
 * Tested: MySQL, H2, PostGreSQL
24
 * Not tested for: SQL Server (throws exception)
25
 *
26
 * @author a.mueller
27
 * @date 16.09.2010
28
 *
29
 */
30
public class UniqueIndexDropper extends AuditedSchemaUpdaterStepBase<UniqueIndexDropper> {
31
	@SuppressWarnings("unused")
32
    private static final Logger logger = Logger.getLogger(UniqueIndexDropper.class);
33

    
34
	private final String indexColumn;
35

    
36
	public static final UniqueIndexDropper NewInstance(String tableName, String indexColumn, boolean includeAudTable){
37
		String stepName = "Drop index " + tableName + "-" + indexColumn;
38
		return new UniqueIndexDropper(stepName, tableName, indexColumn, includeAudTable);
39
	}
40

    
41

    
42
	protected UniqueIndexDropper(String stepName, String tableName, String indexColumn, boolean includeAudTable) {
43
		super(stepName, tableName, includeAudTable);
44
		this.indexColumn = indexColumn;
45
	}
46

    
47
	@Override
48
	protected boolean invokeOnTable(String tableName, ICdmDataSource datasource, IProgressMonitor monitor, CaseType caseType) {
49
		try {
50
			if (checkExists(datasource, caseType)){
51
				String updateQuery = getUpdateQueryString(tableName, datasource, caseType, monitor);
52
				datasource.executeUpdate(updateQuery);
53
			}
54
			return true;
55
		} catch ( Exception e) {
56
			monitor.warning(e.getMessage(), e);
57
			return false;
58
		}
59
	}
60

    
61
	private boolean checkExists(ICdmDataSource datasource, CaseType caseType) throws SQLException, DatabaseTypeNotSupportedException {
62
		DatabaseTypeEnum type = datasource.getDatabaseType();
63
		if (type.equals(DatabaseTypeEnum.MySQL)){
64
			String sql = " SELECT count(*)" +
65
			             " FROM information_schema.KEY_COLUMN_USAGE kcu " +
66
                            " INNER JOIN information_schema.TABLE_CONSTRAINTS tc ON kcu.CONSTRAINT_NAME = tc.CONSTRAINT_NAME " +
67
                            " AND tc.TABLE_NAME = kcu.TABLE_NAME AND tc.TABLE_SCHEMA = kcu.TABLE_SCHEMA " +
68
                         " WHERE kcu.table_name ='@tableName' AND kcu.CONSTRAINT_SCHEMA = '@dbName' " +
69
                            " AND kcu.COLUMN_NAME = '@columnName' AND CONSTRAINT_TYPE = 'UNIQUE' ";
70
			sql = sql.replace("@tableName", tableName);
71
			sql = sql.replace("@columnName", indexColumn);
72
			sql = sql.replace("@dbName", datasource.getDatabase());
73
			long count = (Long)datasource.getSingleValue(sql);
74
			return count > 0;
75
		}else if (type.equals(DatabaseTypeEnum.PostgreSQL)){
76
            String indexName = getIndexName(datasource, caseType);
77
            return indexName != null;
78
		}else if (type.equals(DatabaseTypeEnum.H2)){
79
			String indexName = getIndexName(datasource, caseType);
80
			return indexName != null;
81
		}else{
82
			// not needed
83
			return true;
84
		}
85
	}
86

    
87

    
88
	public String getUpdateQueryString(String tableName, ICdmDataSource datasource, CaseType caseType, IProgressMonitor monitor) throws DatabaseTypeNotSupportedException, SQLException {
89
		//NOTE: no caseType required here
90
		String updateQuery;
91
		DatabaseTypeEnum type = datasource.getDatabaseType();
92
		String indexName = getIndexName(datasource, caseType);
93

    
94
//		if (type.equals(DatabaseTypeEnum.SqlServer2005)){
95
			//MySQL allows both syntaxes
96
//			updateQuery = "ALTER TABLE @tableName ADD @columnName @columnType";
97
//		}else
98
		if (type.equals(DatabaseTypeEnum.H2)){
99
			updateQuery = "ALTER TABLE @tableName DROP CONSTRAINT IF EXISTS @indexName";
100
		}else if (type.equals(DatabaseTypeEnum.PostgreSQL)){
101
//			updateQuery = "DROP INDEX IF EXISTS @indexName";  // does not work because index is used in the constraint
102
//			updateQuery = "ALTER TABLE @tableName DROP CONSTRAINT IF EXISTS @indexName"; //"if exists" does not work (version 8.4)
103
			updateQuery = "ALTER TABLE @tableName DROP CONSTRAINT @indexName";
104
		}else if (type.equals(DatabaseTypeEnum.MySQL)){
105
			updateQuery = "ALTER TABLE @tableName DROP INDEX @indexName";
106
		}else{
107
			updateQuery = null;
108
			String warning = "Update step '" + this.getStepName() + "' is not supported by " + type.getName();
109
			monitor.warning(warning);
110
			throw new DatabaseTypeNotSupportedException(warning);
111
		}
112
		updateQuery = updateQuery.replace("@tableName", tableName);
113
		updateQuery = updateQuery.replace("@indexName", indexName);
114

    
115
		return updateQuery;
116
	}
117

    
118

    
119
	private String getIndexName(ICdmDataSource datasource, CaseType caseType) throws DatabaseTypeNotSupportedException, SQLException {
120
		String result = this.indexColumn;
121
		DatabaseTypeEnum type = datasource.getDatabaseType();
122
		if (type.equals(DatabaseTypeEnum.SqlServer2005)){
123
			throw new DatabaseTypeNotSupportedException(type.toString());
124
		}else if (type.equals(DatabaseTypeEnum.MySQL)){
125
		    String sql = "SELECT kcu.CONSTRAINT_NAME FROM information_schema.KEY_COLUMN_USAGE kcu " +
126
		                    " INNER JOIN information_schema.TABLE_CONSTRAINTS tc ON kcu.CONSTRAINT_NAME = tc.CONSTRAINT_NAME " +
127
		                    " AND tc.TABLE_NAME = kcu.TABLE_NAME AND tc.TABLE_SCHEMA = kcu.TABLE_SCHEMA " +
128
		                    " WHERE kcu.TABLE_NAME = '@tableName' AND kcu.TABLE_SCHEMA = '@dbName' AND kcu.COLUMN_NAME = '@columnName' "+
129
		                        " AND tc.TABLE_NAME = '@tableName' AND tc.TABLE_SCHEMA = '@dbName' AND CONSTRAINT_TYPE = 'UNIQUE' ";
130
		    sql = sql.replace("@tableName", caseType.replaceTableNames(tableName));
131
            sql = sql.replace("@columnName", indexColumn);
132
            sql = sql.replace("@dbName", datasource.getDatabase());
133
            String constraintName = (String)datasource.getSingleValue(sql);
134
            result = constraintName;
135
		}else if (type.equals(DatabaseTypeEnum.H2) ){
136
//			String sql = "SELECT INDEX_NAME FROM INFORMATION_SCHEMA.INDEXES WHERE TABLE_NAME = @tableName AND INDEX_TYPE_NAME = 'UNIQUE INDEX'";
137
			String sql = "SELECT CONSTRAINT_NAME " +
138
					" FROM INFORMATION_SCHEMA.CONSTRAINTS "+
139
					" WHERE CONSTRAINT_CATALOG = '@dbName' AND "+
140
					" TABLE_NAME = '@tableName' AND CONSTRAINT_TYPE = 'UNIQUE' AND "+
141
					" COLUMN_LIST = '@columnName'";
142
			sql = sql.replace("@tableName", tableName.toUpperCase());
143
			sql = sql.replace("@columnName", indexColumn.toUpperCase());
144
			sql = sql.replace("@dbName", datasource.getDatabase().toUpperCase());
145
			String constraintName = (String)datasource.getSingleValue(sql);
146
			result = constraintName;
147
		}else if (type.equals(DatabaseTypeEnum.PostgreSQL)){
148
		    String sql = " SELECT tc.constraint_name " +
149
		            " FROM information_schema.table_constraints tc " +
150
		                " LEFT JOIN information_schema.key_column_usage kcu " +
151
    		                " ON tc.constraint_catalog = kcu.constraint_catalog " +
152
    		                " AND tc.constraint_schema = kcu.constraint_schema " +
153
    		                " AND tc.constraint_name = kcu.constraint_name " +
154
		             " WHERE tc.constraint_type = 'UNIQUE' AND tc.table_name = '@tableName' " +
155
    		                " AND kcu.column_name = '@columnName' AND tc.table_catalog = '@dbName'";
156
            sql = sql.replace("@tableName", tableName.toLowerCase());  //postgres is folding to lower_case not upper case (the later is SQL standard)
157
            sql = sql.replace("@columnName", indexColumn);
158
            sql = sql.replace("@dbName", datasource.getDatabase());
159
            String constraintName = (String)datasource.getSingleValue(sql);
160
            result = constraintName;
161
		}else{
162
			throw new DatabaseTypeNotSupportedException(type.toString());
163
		}
164
		return result;
165

    
166
	}
167

    
168

    
169
}
(32-32/34)