Skip to content

Commit

Permalink
#13309 - Oracle Upsert SQL
Browse files Browse the repository at this point in the history
  • Loading branch information
acurionedotcms committed Jan 8, 2018
1 parent 2251024 commit 1cc3b0c
Show file tree
Hide file tree
Showing 3 changed files with 125 additions and 16 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -50,6 +50,7 @@

import com.liferay.portal.model.User;
import java.lang.reflect.Field;
import java.sql.SQLException;
import java.util.ArrayList;
import java.util.HashMap;
import java.util.HashSet;
Expand Down Expand Up @@ -2292,27 +2293,47 @@ private void deleteInsertPermission(Permissionable permissionable, String type,
dc1.executeUpdate(DELETE_PERMISSIONABLE_REFERENCE_SQL, permissionId);

if (DbConnectionFactory.isPostgres()) {
String query = SQLUtil.generateUpsertSQL("permission_reference", "asset_id", null,
String query = SQLUtil.generateUpsertSQL("permission_reference", "asset_id",
new String[]{"id", "asset_id", "reference_id", "permission_type"},
new String[]{"nextval('permission_reference_seq')", "?", "?", "?"});
new String[]{"nextval('permission_reference_seq')", SQLUtil.PARAMETER, SQLUtil.PARAMETER, SQLUtil.PARAMETER});
dc1.executeUpdate(query, permissionId, newReference.getPermissionId(), type,
permissionId, newReference.getPermissionId(), type);
}
if (DbConnectionFactory.isMySql()) {
String query = SQLUtil.generateUpsertSQL("permission_reference", "asset_id", null,
String query = SQLUtil.generateUpsertSQL("permission_reference", "asset_id",
new String[]{"asset_id", "reference_id", "permission_type"},
new String[]{"?", "?", "?"});
new String[]{SQLUtil.PARAMETER, SQLUtil.PARAMETER, SQLUtil.PARAMETER});
dc1.executeUpdate(query, permissionId, newReference.getPermissionId(), type,
permissionId, newReference.getPermissionId(), type);
}
if (DbConnectionFactory.isMsSql()) {
String query = SQLUtil.generateUpsertSQL("permission_reference", "asset_id", "?",
String query = SQLUtil.generateUpsertSQL("permission_reference", "asset_id",
new String[]{"asset_id", "reference_id", "permission_type"},
new String[]{"?", "?", "?"});
new String[]{SQLUtil.PARAMETER, SQLUtil.PARAMETER, SQLUtil.PARAMETER});
dc1.executeUpdate(query, permissionId,
permissionId, newReference.getPermissionId(), type,
permissionId, newReference.getPermissionId(), type);
}
if (DbConnectionFactory.isOracle()) {
String query = SQLUtil.generateUpsertSQL("permission_reference", "asset_id",
new String[]{"id", "asset_id", "reference_id", "permission_type"},
new String[]{"permission_reference_seq.NEXTVAL", SQLUtil.PARAMETER, SQLUtil.PARAMETER, SQLUtil.PARAMETER});
try {
//In Oracle the Upsert (Merge) is not thread safe. Attempt to insert first:
dc1.executeUpdate(query, false,
permissionId, newReference.getPermissionId(), type,
permissionId, newReference.getPermissionId(), type);
} catch (DotDataException ex) {
if (SQLUtil.isUniqueConstraintException(ex)) {
//On Unique constraint exception, attempt to update:
dc1.executeUpdate(query, permissionId,
newReference.getPermissionId(), type,
permissionId, newReference.getPermissionId(), type);
} else {
throw ex;
}
}
}
}

} catch(Exception exception){
Expand Down
40 changes: 36 additions & 4 deletions dotCMS/src/main/java/com/dotmarketing/common/db/DotConnect.java
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,7 @@
import java.sql.ResultSet;
import java.sql.ResultSetMetaData;
import java.sql.SQLException;
import java.sql.SQLIntegrityConstraintViolationException;
import java.sql.Statement;
import java.sql.Timestamp;
import java.util.*;
Expand Down Expand Up @@ -1096,11 +1097,25 @@ private void setParams(final PreparedStatement preparedStatement,
* Executes an update operation for a preparedStatement, returns the number of affected rows.
* If the connection is get from a transaction context, will used it. Otherwise will create and handle an atomic transaction.
* @param preparedStatement String
* @param logException when an exception occurs, whether or not to log the exception as Error in log file
* @param parameters Object array of parameters for the preparedStatement (if it does not have any, can be null). Not any checking of them
* @return int rows affected
* @throws DotDataException
*/
public int executeUpdate (final String preparedStatement,
final Object... parameters) throws DotDataException {
return executeUpdate(preparedStatement, true, parameters);
}

/**
* Executes an update operation for a preparedStatement, returns the number of affected rows.
* If the connection is get from a transaction context, will used it. Otherwise will create and handle an atomic transaction.
* @param preparedStatement String
* @param parameters Object array of parameters for the preparedStatement (if it does not have any, can be null). Not any checking of them
* @return int rows affected
* @throws DotDataException
*/
public int executeUpdate (final String preparedStatement, Boolean logException,
final Object... parameters) throws DotDataException {

final boolean isNewTransaction = DbConnectionFactory.startTransactionIfNeeded();
Expand All @@ -1111,7 +1126,7 @@ public int executeUpdate (final String preparedStatement,

connection = DbConnectionFactory.getConnection();
rowsAffected = this.executeUpdate(connection,
preparedStatement, parameters);
preparedStatement, logException, parameters);

if (isNewTransaction) {
connection.commit();
Expand All @@ -1124,7 +1139,9 @@ public int executeUpdate (final String preparedStatement,
throw e;
} catch (Exception e) {

Logger.error(DotConnect.class, e.getMessage(), e);
if (logException) {
Logger.error(DotConnect.class, e.getMessage(), e);
}
throw new DotDataException(e.getMessage(), e);
} finally {

Expand Down Expand Up @@ -1157,6 +1174,20 @@ protected void rollback(final Connection connection) throws DotDataException {
* @throws DotDataException
*/
public int executeUpdate (final Connection connection, final String preparedStatementString,
final Object... parameters) throws DotDataException {
return executeUpdate(connection, preparedStatementString, true, parameters);
}

/**
* Executes an update operation for a preparedStatement
* @param connection {@link Connection}
* @param preparedStatementString String
* @param logException when an exception occurs, whether or not to log the exception as Error in log file
* @param parameters Object array of parameters for the preparedStatement (if it does not have any, can be null). Not any checking of them
* @return int rows affected
* @throws DotDataException
*/
public int executeUpdate (final Connection connection, final String preparedStatementString, Boolean logException,
final Object... parameters) throws DotDataException {


Expand All @@ -1169,8 +1200,9 @@ public int executeUpdate (final Connection connection, final String preparedStat
this.setParams(preparedStatement, parameters);
rowsAffected = preparedStatement.executeUpdate();
} catch (SQLException e) {

Logger.error(DotConnect.class, e.getMessage(), e);
if (logException) {
Logger.error(DotConnect.class, e.getMessage(), e);
}
throw new DotDataException(e.getMessage(), e);
} finally {

Expand Down
68 changes: 62 additions & 6 deletions dotCMS/src/main/java/com/dotmarketing/common/util/SQLUtil.java
Original file line number Diff line number Diff line change
Expand Up @@ -7,12 +7,14 @@
import com.dotmarketing.business.APILocator;
import com.dotmarketing.business.DotStateException;
import com.dotmarketing.db.DbConnectionFactory;
import com.dotmarketing.exception.DotDataException;
import com.dotmarketing.exception.DotRuntimeException;
import com.dotmarketing.util.Logger;
import com.dotmarketing.util.SecurityLogger;
import com.dotmarketing.util.UtilMethods;
import com.liferay.util.StringPool;
import com.liferay.util.StringUtil;
import java.sql.SQLException;
import java.util.ArrayList;
import java.util.List;
import java.util.Set;
Expand All @@ -38,6 +40,9 @@ public class SQLUtil {
public static final String DESC = "desc";
public static final String _ASC = " " + ASC ;
public static final String _DESC = " " + DESC;
public static final String PARAMETER = "?";

private static final String SQL_STATE_UNIQUE_CONSTRAINT = "23000";

private static final Set<String> EVIL_SQL_CONDITION_WORDS = ImmutableSet.of( "insert", "delete", "update",
"replace", "create", "drop", "alter", "truncate", "declare", "exec", "--", "procedure", "pg_", "lock",
Expand Down Expand Up @@ -311,15 +316,27 @@ private static boolean isValidSQLCharacter (final char c) {
return Character.isLetterOrDigit(c) || '-' == c || '_' == c;
} // isValidSQLCharacter.

// Postgres Upsert Example:
// INSERT INTO table (columns) VALUES (values)
// ON CONFLICT (conditionalColumn) DO UPDATE SET column1=value1, column2=value2, etc...
private final static String POSTGRES_UPSERT_QUERY =
"INSERT INTO %s (%s) "
+ "VALUES (%s) ON CONFLICT (%s) "
+ "DO UPDATE SET %s";

// MySQL Upsert Example:
// INSERT INTO table (columns) VALUES (values)
// ON DUPLICATE KEY UPDATE column1=value1, column2=value2, etc...
private final static String MYSQL_UPSERT_QUERY =
"INSERT INTO %s (%s) "
+ "VALUES (%s) ON DUPLICATE KEY "
+ "UPDATE %s";

// MSSQL Server Upsert Example:
// MERGE table WITH (HOLDLOCK) AS [Target] USING
// (SELECT conditionalValue AS conditionalColumn) AS [Source] ON [Target].conditionalColumn = [Source].conditionalColumn
// WHEN MATCHED THEN UPDATE SET column1=value1, column2=value2, etc...
// WHEN NOT MATCHED THEN INSERT (columns) VALUES (values);
private final static String MSSQL_UPSERT_QUERY =
"MERGE %s WITH (HOLDLOCK) AS [Target] USING "
+ "(SELECT %s AS %s) AS [Source] ON [Target].%s = [Source].%s "
Expand All @@ -329,34 +346,66 @@ private static boolean isValidSQLCharacter (final char c) {
+ " INSERT (%s) "
+ " VALUES (%s);";

public static String generateUpsertSQL (String table, String conditionalColumn, String conditionalValue, String[] columns, String[] values) {
// Oracle Upsert Example:
// INSERT INTO table Target USING
// (SELECT conditionalValue conditionalColumn FROM dual) Source ON (Target.conditionalColumn = Source.conditionalColumn)
// WHEN MATCHED THEN UPDATE SET column1=value1, column2=value2, etc...
// WHEN NOT MATCHED THEN INSERT (columns) VALUES (values)
private final static String ORACLE_UPSERT_QUERY =
"MERGE INTO %s Target USING "
+ "(SELECT %s %s FROM DUAL) Source ON (Target.%s = Source.%s) "
+ "WHEN MATCHED THEN "
+ " UPDATE SET %s "
+ "WHEN NOT MATCHED THEN "
+ " INSERT (%s) "
+ " VALUES (%s)";

public static String generateUpsertSQL (String table, String conditionalColumn, String[] columns, String[] values) {
String query = null;

//Generate column = value pairs, used for the Update part
//Update Parameters: Generate column = value pairs, used for the Update part
StringBuffer buffer = new StringBuffer();
for (int i = 0; i < columns.length; i++) {
if (DbConnectionFactory.isOracle() && columns[i].equals(conditionalColumn)) {
//In Oracle, the conditionalColumn cannot be part of the update
continue;
}
buffer.append(columns[i] + " = " + values[i]);
if (i < (columns.length -1)) {
buffer.append(", ");
}
}

if (DbConnectionFactory.isPostgres()) {
query = String.format(POSTGRES_UPSERT_QUERY, table,
query = String.format(POSTGRES_UPSERT_QUERY,
table,
StringUtil.merge(columns),
StringUtil.merge(values),
conditionalColumn,
buffer.toString());
}
if (DbConnectionFactory.isMySql()) {
query = String.format(MYSQL_UPSERT_QUERY, table,
query = String.format(MYSQL_UPSERT_QUERY,
table,
StringUtil.merge(columns),
StringUtil.merge(values),
buffer.toString());
}
if (DbConnectionFactory.isMsSql()) {
query = String.format(MSSQL_UPSERT_QUERY, table,
conditionalValue,
query = String.format(MSSQL_UPSERT_QUERY,
table,
PARAMETER,
conditionalColumn,
conditionalColumn,
conditionalColumn,
buffer.toString(),
StringUtil.merge(columns),
StringUtil.merge(values));
}
if (DbConnectionFactory.isOracle()) {
query = String.format(ORACLE_UPSERT_QUERY,
table,
PARAMETER,
conditionalColumn,
conditionalColumn,
conditionalColumn,
Expand All @@ -368,4 +417,11 @@ public static String generateUpsertSQL (String table, String conditionalColumn,
return query;
}

public static boolean isUniqueConstraintException (DotDataException ex) {
if (ex != null && ex.getCause() instanceof SQLException) {
return ((SQLException) ex.getCause()).getSQLState().equals(SQL_STATE_UNIQUE_CONSTRAINT);
}
return false;
}

} // E:O:F:SQLUtil.

0 comments on commit 1cc3b0c

Please sign in to comment.