Aggiunta funzione per clonare tabelle nel database
All checks were successful
IntegryManagementSystem_Multi/pipeline/head This commit looks good
All checks were successful
IntegryManagementSystem_Multi/pipeline/head This commit looks good
This commit is contained in:
@@ -155,6 +155,11 @@ public abstract class BaseMigration implements MigrationModelInterface {
|
||||
UtilityDB.createIndex(connection, indexTableDTO);
|
||||
}
|
||||
|
||||
|
||||
protected void cloneTable(String sourceTable, String newTable,boolean fillNewTable, boolean dropOldTable, boolean renameNewTable) throws Exception {
|
||||
UtilityDB.cloneTable(connection, sourceTable, newTable, fillNewTable, dropOldTable, renameNewTable);
|
||||
}
|
||||
|
||||
protected void dropIndex(String tableName, String indexName) throws Exception {
|
||||
UtilityDB.dropIndex(connection, tableName, indexName);
|
||||
}
|
||||
|
||||
@@ -31,6 +31,7 @@ import java.time.LocalDate;
|
||||
import java.time.LocalDateTime;
|
||||
import java.util.Date;
|
||||
import java.util.*;
|
||||
import java.util.stream.Collectors;
|
||||
|
||||
import static it.integry.ems_model.utility.UtilityString.countSeparator;
|
||||
import static it.integry.ems_model.utility.UtilityString.replaceSubString;
|
||||
@@ -740,4 +741,136 @@ public class UtilityDB {
|
||||
return result;
|
||||
}
|
||||
|
||||
public static void cloneTable(Connection conn, String sourceTable, String newTable,boolean fillNewTable, boolean dropOldTable, boolean renameNewTable) throws Exception {
|
||||
//CREAZIONE TABELLA NUOVA
|
||||
executeStatement(conn, String.format("SELECT TOP 0 * INTO %s FROM %s", newTable, sourceTable));
|
||||
|
||||
String fileGroup = executeSimpleQueryOnlyFirstRowFirstColumn(conn,
|
||||
Query.format("SELECT fg.name\n" +
|
||||
"FROM sys.tables AS t \n" +
|
||||
"inner JOIN sys.indexes AS i ON t.object_id = i.object_id \n" +
|
||||
"inner JOIN sys.filegroups AS fg ON i.data_space_id = fg.data_space_id \n" +
|
||||
"WHERE t.name = %s\n" +
|
||||
"and i.type = 1", sourceTable));
|
||||
|
||||
String sql =
|
||||
Query.format("SELECT c.name\n" +
|
||||
"FROM sys.key_constraints kc\n" +
|
||||
" JOIN sys.index_columns ic ON kc.parent_object_id = ic.object_id AND kc.unique_index_id = ic.index_id\n" +
|
||||
" JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id\n" +
|
||||
"\n" +
|
||||
"WHERE kc.parent_object_id = OBJECT_ID(%s)\n" +
|
||||
" AND kc.type = 'PK'\n" +
|
||||
"ORDER BY ic.key_ordinal", sourceTable);
|
||||
|
||||
List<String> listColPK = UtilityDB.executeSimpleQueryOnlyFirstColumn(conn, sql);
|
||||
|
||||
//Creazione PK
|
||||
executeStatement(conn,
|
||||
String.format("ALTER TABLE %s ADD CONSTRAINT [pk_%s] PRIMARY KEY ( %s ) %s",
|
||||
newTable, newTable, StringUtils.join(listColPK, ","),
|
||||
(fileGroup.equalsIgnoreCase("PRIMARY") ? "" : "ON " + fileGroup)));
|
||||
|
||||
//Creazione indici
|
||||
sql =
|
||||
Query.format(
|
||||
"SELECT i.name as index_name, i.is_unique, fg.name as file_name\n" +
|
||||
"FROM sys.indexes i inner join sys.tables AS t on i.object_id = t.object_id \n" +
|
||||
"JOIN sys.filegroups AS fg ON i.data_space_id = fg.data_space_id and i.is_primary_key = 1 \n" +
|
||||
"WHERE i.object_id = OBJECT_ID(%s)\n" +
|
||||
" AND i.is_primary_key = 0\n" +
|
||||
" AND i.is_unique_constraint = 0", sourceTable
|
||||
);
|
||||
|
||||
List<HashMap<String, Object>> indexList = UtilityDB.executeSimpleQuery(conn, sql);
|
||||
|
||||
for(HashMap<String, Object> i: indexList) {
|
||||
sql = Query.format(
|
||||
"SELECT c.name\n" +
|
||||
"FROM sys.indexes i\n" +
|
||||
"JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id\n" +
|
||||
"JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id\n" +
|
||||
"WHERE i.object_id = OBJECT_ID(%s)\n" +
|
||||
" AND i.name = %s\n" +
|
||||
"ORDER BY ic.key_ordinal",
|
||||
sourceTable, i.get("index_name")
|
||||
);
|
||||
|
||||
List<String> listColIndex = UtilityDB.executeSimpleQueryOnlyFirstColumn(conn, sql);
|
||||
|
||||
executeStatement(conn, String.format("CREATE %s INDEX %s ON %s ( %s ) %s",
|
||||
(Boolean.TRUE.equals(i.get("is_unique")) ? "UNIQUE" : ""),
|
||||
i.get("index_name"),
|
||||
newTable,
|
||||
StringUtils.join(listColIndex, ","),
|
||||
((String) i.get("file_name")).equalsIgnoreCase("PRIMARY") ? "" : "ON " + (String) i.get("file_name")
|
||||
));
|
||||
}
|
||||
|
||||
|
||||
//creazione default
|
||||
sql = Query.format("SELECT \n" +
|
||||
" dc.name AS DefaultName,\n" +
|
||||
" c.name AS ColumnName,\n" +
|
||||
" dc.definition\n" +
|
||||
"FROM sys.default_constraints dc\n" +
|
||||
"JOIN sys.columns c ON dc.parent_object_id = c.object_id AND dc.parent_column_id = c.column_id\n" +
|
||||
"WHERE dc.parent_object_id = OBJECT_ID(%s)",
|
||||
sourceTable);
|
||||
|
||||
List<HashMap<String, Object>> listDefatult = UtilityDB.executeSimpleQuery(conn, sql);
|
||||
|
||||
for(HashMap<String, Object> i: listDefatult) {
|
||||
executeStatement(conn, String.format("ALTER TABLE %s ADD CONSTRAINT %s DEFAULT %s FOR %s",
|
||||
newTable,
|
||||
((String) i.get("DefaultName")).toLowerCase().replace(sourceTable.toLowerCase(), newTable.toLowerCase()),
|
||||
i.get("definition"),
|
||||
i.get("ColumnName")
|
||||
));
|
||||
}
|
||||
|
||||
//creazione foreign key
|
||||
sql = Query.format("SELECT fk.name as fk_name, OBJECT_NAME(fk.referenced_object_id) as ref_tab\n" +
|
||||
"FROM sys.foreign_keys fk\n" +
|
||||
"WHERE fk.parent_object_id = OBJECT_ID(%s);",
|
||||
sourceTable);
|
||||
|
||||
List<HashMap<String, Object>> listFk = UtilityDB.executeSimpleQuery(conn, sql);
|
||||
|
||||
for(HashMap<String, Object> fk: listFk) {
|
||||
sql = String.format(
|
||||
"SELECT COL_NAME(fkc.parent_object_id, fkc.parent_column_id) AS column_name, \n" +
|
||||
"COL_NAME(fkc.referenced_object_id, fkc.referenced_column_id) AS column_ref\n" +
|
||||
"FROM sys.foreign_keys fk\n" +
|
||||
"INNER JOIN sys.foreign_key_columns fkc ON fk.object_id = fkc.constraint_object_id\n" +
|
||||
"WHERE fk.parent_object_id = OBJECT_ID(%s) AND fk.name = %S;",sourceTable, fk.get("fk_name")
|
||||
);
|
||||
|
||||
List<HashMap<String, Object>> listFkColumns = UtilityDB.executeSimpleQuery(conn, sql);
|
||||
|
||||
String colNames = StringUtils.join(listFkColumns.stream().map(x -> (String)x.get("column_name")).collect(Collectors.toList()), ",");
|
||||
String colRef = StringUtils.join(listFkColumns.stream().map(x -> (String)x.get("column_ref")).collect(Collectors.toList()), ",");
|
||||
|
||||
sql = String.format("ALTER TABLE %s ADD CONSTRAINT [ %s_NEW] FOREIGN KEY ([%s]) REFERENCES [%s]([%s]);",
|
||||
newTable,
|
||||
fk.get("fk_name"),
|
||||
colNames,
|
||||
fk.get("ref_tab"),
|
||||
colRef
|
||||
);
|
||||
|
||||
executeStatement(conn, sql);
|
||||
}
|
||||
//RIEMPIMENTO TABELLA NUOVA
|
||||
if (fillNewTable) {
|
||||
executeStatement(conn, String.format("INSERT INTO %s SELECT * FROM %s", newTable, sourceTable));
|
||||
|
||||
if (dropOldTable) {
|
||||
executeStatement(conn, "DROP TABLE " + sourceTable);
|
||||
if (renameNewTable)
|
||||
executeStatement(conn, Query.format("EXEC sp_rename %s, %s;", newTable, sourceTable));
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
}
|
||||
|
||||
Reference in New Issue
Block a user