From c8300d43262cc434fc1e6cff02707137c1abbb48 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Lukas=20W=C3=B6hrl?= Date: Fri, 29 Jan 2016 12:05:42 +0100 Subject: [PATCH 1/5] mssql trigger: changed from cursor to dml to allow correct usage of column values in EXTERNAL_SELECT statements --- .../db/mssql/MsSqlTriggerTemplate.java | 126 +++++++----------- 1 file changed, 45 insertions(+), 81 deletions(-) diff --git a/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java b/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java index 155d44f4bb..65f319eab9 100644 --- a/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java +++ b/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java @@ -70,28 +70,19 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " set @NCT = @@OPTIONS & 512 \n" + " set nocount on \n" + " declare @TransactionId varchar(1000) \n" + -" declare @DataRow "+(castToNVARCHAR ? "n" : "")+"varchar(max) \n" + -" declare @ChannelId varchar(128) \n" + -" $(declareNewKeyVariables) \n" + " if (@@TRANCOUNT > 0) begin \n" + " select @TransactionId = convert(VARCHAR(1000),transaction_id) from sys.dm_exec_requests where session_id=@@SPID and open_transaction_count > 0 \n" + " end \n" + " if ($(syncOnIncomingBatchCondition)) begin \n" + -" declare DataCursor cursor local for \n" + +" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data \n" + +" (table_name, event_type, trigger_hist_id, row_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + +" select '$(targetTableName)','I', $(triggerHistoryId), $(columns), \n" + +" $(channelExpression), $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp \n" + " $(if:containsBlobClobColumns) \n" + -" select $(columns) $(newKeyNames), $(channelExpression) from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) where $(syncOnInsertCondition)\n" + +" from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) where $(syncOnInsertCondition)\n" + " $(else:containsBlobClobColumns) \n" + -" select $(columns) $(newKeyNames), $(channelExpression) from inserted where $(syncOnInsertCondition) \n" + +" from inserted where $(syncOnInsertCondition) \n" + " $(end:containsBlobClobColumns) \n" + -" open DataCursor \n" + -" fetch next from DataCursor into @DataRow $(newKeyVariables), @ChannelId \n" + -" while @@FETCH_STATUS = 0 begin \n" + -" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, row_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + -" values('$(targetTableName)','I', $(triggerHistoryId), @DataRow, @ChannelId, $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp) \n" + -" fetch next from DataCursor into @DataRow $(newKeyVariables), @ChannelId \n" + -" end \n" + -" close DataCursor \n" + -" deallocate DataCursor \n" + " end \n" + " $(custom_on_insert_text) \n" + " if (@NCT = 0) set nocount off \n" + @@ -105,33 +96,18 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " set @NCT = @@OPTIONS & 512 \n" + " set nocount on \n" + " declare @TransactionId varchar(1000) \n" + -" declare @DataRow "+(castToNVARCHAR ? "n" : "")+"varchar(max) \n" + -" declare @OldPk "+(castToNVARCHAR ? "n" : "")+"varchar(2000) \n" + -" declare @OldDataRow "+(castToNVARCHAR ? "n" : "")+"varchar(max) \n" + -" declare @ChannelId varchar(128) \n" + -" $(declareOldKeyVariables) \n" + -" $(declareNewKeyVariables) \n" + " if (@@TRANCOUNT > 0) begin \n" + " select @TransactionId = convert(VARCHAR(1000),transaction_id) from sys.dm_exec_requests where session_id=@@SPID and open_transaction_count > 0 \n" + " end \n" + " if ($(syncOnIncomingBatchCondition)) begin \n" + -" declare DataCursor cursor local for \n" + +" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, row_data, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + +" select '$(targetTableName)','U', $(triggerHistoryId), $(columns), $(oldKeys), $(oldColumns), $(channelExpression), "+ +" $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp\n" + " $(if:containsBlobClobColumns) \n" + -" select $(columns), $(oldKeys), $(oldColumns) $(oldKeyNames) $(newKeyNames), $(channelExpression) from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) inner join deleted on $(oldNewPrimaryKeyJoin) where $(syncOnUpdateCondition)\n" + +" from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) inner join deleted on $(oldNewPrimaryKeyJoin) where $(syncOnUpdateCondition)\n" + " $(else:containsBlobClobColumns) \n" + -" select $(columns), $(oldKeys), $(oldColumns) $(oldKeyNames) $(newKeyNames), $(channelExpression) from inserted inner join deleted on $(oldNewPrimaryKeyJoin) where $(syncOnUpdateCondition) \n" + +" from inserted inner join deleted on $(oldNewPrimaryKeyJoin) where $(syncOnUpdateCondition) \n" + " $(end:containsBlobClobColumns) \n" + -" open DataCursor \n" + -" fetch next from DataCursor into @DataRow, @OldPk, @OldDataRow $(oldKeyVariables) $(newKeyVariables), @ChannelId \n" + -" while @@FETCH_STATUS = 0 begin \n" + -" if ($(dataHasChangedCondition)) begin \n" + -" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, row_data, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + -" values('$(targetTableName)','U', $(triggerHistoryId), @DataRow, @OldPk, @OldDataRow, @ChannelId, $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp)\n" + -" end \n" + -" fetch next from DataCursor into @DataRow, @OldPk, @OldDataRow $(oldKeyVariables) $(newKeyVariables), @ChannelId \n" + -" end \n" + -" close DataCursor \n" + -" deallocate DataCursor \n" + " end \n" + " $(custom_on_update_text) \n" + " if (@NCT = 0) set nocount off \n" + @@ -145,41 +121,19 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " set @NCT = @@OPTIONS & 512 \n" + " set nocount on \n" + " declare @TransactionId varchar(1000) \n" + -" declare @OldPk "+(castToNVARCHAR ? "n" : "")+"varchar(2000) \n" + -" declare @OldDataRow "+(castToNVARCHAR ? "n" : "")+"varchar(max) \n" + -" declare @DataRow "+(castToNVARCHAR ? "n" : "")+"varchar(max) \n" + -" declare @ChannelId varchar(128) \n" + -" $(declareOldKeyVariables) \n" + -" $(declareNewKeyVariables) \n" + " \n" + " if (@@TRANCOUNT > 0) begin \n" + " select @TransactionId = convert(VARCHAR(1000),transaction_id) from sys.dm_exec_requests where session_id=@@SPID and open_transaction_count > 0 \n" + " end \n" + " if ($(syncOnIncomingBatchCondition)) begin \n" + -" declare DeleteCursor cursor local for \n" + -" select $(oldKeys), $(oldColumns) $(oldKeyNames) from deleted where $(syncOnDeleteCondition) \n" + -" declare InsertCursor cursor local for \n" + -" $(if:containsBlobClobColumns) \n" + -" select $(columns) $(newKeyNames), $(channelExpression) from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) where $(syncOnInsertCondition)\n" + -" $(else:containsBlobClobColumns) \n" + -" select $(columns) $(newKeyNames), $(channelExpression) from inserted where $(syncOnInsertCondition) \n" + -" $(end:containsBlobClobColumns) \n" + -" open DeleteCursor \n" + -" open InsertCursor \n" + -" fetch next from DeleteCursor into @OldPk, @OldDataRow $(oldKeyVariables) \n" + -" fetch next from InsertCursor into @DataRow $(newKeyVariables), @ChannelId \n" + -" while @@FETCH_STATUS = 0 begin \n" + -" if ($(dataHasChangedCondition)) begin \n" + -" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, row_data, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + -" values('$(targetTableName)','U', $(triggerHistoryId), @DataRow, @OldPk, @OldDataRow, @ChannelId, $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp)\n" + -" end \n" + -" fetch next from DeleteCursor into @OldPk, @OldDataRow $(oldKeyVariables) \n" + -" fetch next from InsertCursor into @DataRow $(newKeyVariables), @ChannelId \n" + -" end \n" + -" close DeleteCursor \n" + -" close InsertCursor \n" + -" deallocate DeleteCursor \n" + -" deallocate InsertCursor \n" + +" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, row_data, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + +" select '$(targetTableName)','U', $(triggerHistoryId), $(columns), $(oldKeys), $(oldColumns), $(channelExpression), "+ +" $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp\n" + +" $(if:containsBlobClobColumns) \n" + +" from (select $(nonBlobColumns), row_number() over (order by (select 1)) as __row_num from inserted) inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) inner join (select $(nonBlobColumns), row_number() over (order by (select 1)) as __row_num from deleted)deleted on (inserted.__row_num = deleted.__row_num) where $(syncOnUpdateCondition)\n" + +" $(else:containsBlobClobColumns) \n" + +" from (select *, row_number() over (order by (select 1)) as __row_num from inserted) inserted inner join (select *, row_number() over (order by (select 1)) as __row_num from deleted) deleted on (inserted.__row_num = deleted.__row_num) where $(syncOnUpdateCondition) \n" + +" $(end:containsBlobClobColumns) \n" + " end \n" + " $(custom_on_update_text) \n" + " if (@NCT = 0) set nocount off \n" + @@ -193,25 +147,14 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " set @NCT = @@OPTIONS & 512 \n" + " set nocount on \n" + " declare @TransactionId varchar(1000) \n" + -" declare @OldPk "+(castToNVARCHAR ? "n" : "")+"varchar(2000) \n" + -" declare @OldDataRow "+(castToNVARCHAR ? "n" : "")+"varchar(max) \n" + -" declare @ChannelId varchar(128) \n" + -" $(declareOldKeyVariables) \n" + " if (@@TRANCOUNT > 0) begin \n" + " select @TransactionId = convert(VARCHAR(1000),transaction_id) from sys.dm_exec_requests where session_id=@@SPID and open_transaction_count > 0 \n" + " end \n" + " if ($(syncOnIncomingBatchCondition)) begin \n" + -" declare DataCursor cursor local for \n" + -" select $(oldKeys), $(oldColumns) $(oldKeyNames), $(channelExpression) from deleted where $(syncOnDeleteCondition) \n" + -" open DataCursor \n" + -" fetch next from DataCursor into @OldPk, @OldDataRow $(oldKeyVariables), @ChannelId \n" + -" while @@FETCH_STATUS = 0 begin \n" + -" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + -" values('$(targetTableName)','D', $(triggerHistoryId), @OldPk, @OldDataRow, @ChannelId, $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp)\n" + -" fetch next from DataCursor into @OldPk,@OldDataRow $(oldKeyVariables), @ChannelId \n" + -" end \n" + -" close DataCursor \n" + -" deallocate DataCursor \n" + +" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + +" select '$(targetTableName)','D', $(triggerHistoryId), $(oldKeys), $(oldColumns), $(channelExpression), \n" + +" $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp\n" + +" from deleted where $(syncOnDeleteCondition) \n" + " end \n" + " $(custom_on_delete_text) \n" + " if (@NCT = 0) set nocount off \n" + @@ -234,11 +177,32 @@ protected String replaceTemplateVariables(DataEventType dml, Trigger trigger, buildKeyVariablesDeclare(columns, "old"), ddl); ddl = FormatUtils.replace("declareNewKeyVariables", buildKeyVariablesDeclare(columns, "new"), ddl); + + ddl = FormatUtils.replace("nonBlobColumns", buildNonLobColumnsString(table), ddl); return ddl; } + + private String buildNonLobColumnsString(Table table){ + StringBuilder builder = new StringBuilder(); + + for(Column column : table.getColumns()){ + boolean isLob = symmetricDialect.getPlatform().isLob(column.getMappedTypeCode()); + if(isLob){ + continue; + } + if(builder.length() > 0){ + builder.append(","); + } + builder.append('"'); + builder.append(column.getName()); + builder.append('"'); + } + + return builder.toString(); + } @Override protected boolean requiresEmptyLobTemplateForDeletes() { return true; } -} \ No newline at end of file +} From 1ee62c372693ce324855ef5a6b964e029491f2f9 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Lukas=20W=C3=B6hrl?= Date: Mon, 1 Feb 2016 09:37:36 +0100 Subject: [PATCH 2/5] take dataHasChangedCondition into account --- .../db/mssql/MsSqlTriggerTemplate.java | 39 ++++++++++++++++--- 1 file changed, 33 insertions(+), 6 deletions(-) diff --git a/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java b/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java index 65f319eab9..74a48fd770 100644 --- a/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java +++ b/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java @@ -79,10 +79,11 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " select '$(targetTableName)','I', $(triggerHistoryId), $(columns), \n" + " $(channelExpression), $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp \n" + " $(if:containsBlobClobColumns) \n" + -" from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) where $(syncOnInsertCondition)\n" + +" from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) \n" + " $(else:containsBlobClobColumns) \n" + -" from inserted where $(syncOnInsertCondition) \n" + +" from inserted \n" + " $(end:containsBlobClobColumns) \n" + +" where $(syncOnInsertCondition) \n" + " end \n" + " $(custom_on_insert_text) \n" + " if (@NCT = 0) set nocount off \n" + @@ -104,10 +105,11 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " select '$(targetTableName)','U', $(triggerHistoryId), $(columns), $(oldKeys), $(oldColumns), $(channelExpression), "+ " $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp\n" + " $(if:containsBlobClobColumns) \n" + -" from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) inner join deleted on $(oldNewPrimaryKeyJoin) where $(syncOnUpdateCondition)\n" + +" from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) inner join deleted on $(oldNewPrimaryKeyJoin) \n" + " $(else:containsBlobClobColumns) \n" + -" from inserted inner join deleted on $(oldNewPrimaryKeyJoin) where $(syncOnUpdateCondition) \n" + +" from inserted inner join deleted on $(oldNewPrimaryKeyJoin) \n" + " $(end:containsBlobClobColumns) \n" + +" where $(syncOnUpdateCondition) and ($(dataHasChangedCondition)) \n" + " end \n" + " $(custom_on_update_text) \n" + " if (@NCT = 0) set nocount off \n" + @@ -130,10 +132,11 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " select '$(targetTableName)','U', $(triggerHistoryId), $(columns), $(oldKeys), $(oldColumns), $(channelExpression), "+ " $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp\n" + " $(if:containsBlobClobColumns) \n" + -" from (select $(nonBlobColumns), row_number() over (order by (select 1)) as __row_num from inserted) inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) inner join (select $(nonBlobColumns), row_number() over (order by (select 1)) as __row_num from deleted)deleted on (inserted.__row_num = deleted.__row_num) where $(syncOnUpdateCondition)\n" + +" from (select $(nonBlobColumns), row_number() over (order by (select 1)) as __row_num from inserted) inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) inner join (select $(nonBlobColumns), row_number() over (order by (select 1)) as __row_num from deleted)deleted on (inserted.__row_num = deleted.__row_num)\n" + " $(else:containsBlobClobColumns) \n" + -" from (select *, row_number() over (order by (select 1)) as __row_num from inserted) inserted inner join (select *, row_number() over (order by (select 1)) as __row_num from deleted) deleted on (inserted.__row_num = deleted.__row_num) where $(syncOnUpdateCondition) \n" + +" from (select *, row_number() over (order by (select 1)) as __row_num from inserted) inserted inner join (select *, row_number() over (order by (select 1)) as __row_num from deleted) deleted on (inserted.__row_num = deleted.__row_num) \n" + " $(end:containsBlobClobColumns) \n" + +" where $(syncOnUpdateCondition) and ($(dataHasChangedCondition)) \n" + " end \n" + " $(custom_on_update_text) \n" + " if (@NCT = 0) set nocount off \n" + @@ -178,10 +181,34 @@ protected String replaceTemplateVariables(DataEventType dml, Trigger trigger, ddl = FormatUtils.replace("declareNewKeyVariables", buildKeyVariablesDeclare(columns, "new"), ddl); + ddl = FormatUtils.replace("anyNonBlobColumnChanged", + buildNonLobColumnsAreNotEqualString(table, "inserted", "deleted"), ddl); + ddl = FormatUtils.replace("nonBlobColumns", buildNonLobColumnsString(table), ddl); return ddl; } + private String buildNonLobColumnsAreNotEqualString(Table table, String table1Name, String table2Name){ + StringBuilder builder = new StringBuilder(); + + for(Column column : table.getColumns()){ + boolean isLob = symmetricDialect.getPlatform().isLob(column.getMappedTypeCode()); + + if(isLob || column.isPrimaryKey()){ + continue; + } + if(builder.length() > 0){ + builder.append(" and "); + } + + builder.append(String.format("%s.\"%s\"=%s.\"%s\"", + table1Name, column.getName(), table2Name, column.getName())); + + } + + return "not (" + builder.toString() + ")"; + } + private String buildNonLobColumnsString(Table table){ StringBuilder builder = new StringBuilder(); From 0b6bf63532703422ab5daca329f34b969cb309f9 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Lukas=20W=C3=B6hrl?= Date: Mon, 1 Feb 2016 09:38:31 +0100 Subject: [PATCH 3/5] use template parameter which gets replace on template generation --- .../org/jumpmind/symmetric/db/mssql/MsSqlSymmetricDialect.java | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlSymmetricDialect.java b/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlSymmetricDialect.java index 1c454c7c07..18bc9df868 100644 --- a/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlSymmetricDialect.java +++ b/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlSymmetricDialect.java @@ -369,7 +369,8 @@ public boolean needsToSelectLobData() { @Override protected String getDbSpecificDataHasChangedCondition(Trigger trigger) { - return "@OldDataRow is null or @DataRow != @OldDataRow"; + /* gets filled/replaced by trigger template as it will compare by each column */ + return "$(anyNonBlobColumnChanged)"; } } From 71df116e8a176da38ca423f6068c1a182ba684ff Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Lukas=20W=C3=B6hrl?= Date: Mon, 1 Feb 2016 16:18:16 +0100 Subject: [PATCH 4/5] take into account that changed values could be null which need different comparison --- .../symmetric/db/mssql/MsSqlTriggerTemplate.java | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java b/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java index 74a48fd770..f4c25b28c0 100644 --- a/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java +++ b/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java @@ -182,7 +182,7 @@ protected String replaceTemplateVariables(DataEventType dml, Trigger trigger, buildKeyVariablesDeclare(columns, "new"), ddl); ddl = FormatUtils.replace("anyNonBlobColumnChanged", - buildNonLobColumnsAreNotEqualString(table, "inserted", "deleted"), ddl); + buildNonLobColumnsAreNotEqualString(table, newTriggerValue, oldTriggerValue), ddl); ddl = FormatUtils.replace("nonBlobColumns", buildNonLobColumnsString(table), ddl); return ddl; @@ -198,15 +198,15 @@ private String buildNonLobColumnsAreNotEqualString(Table table, String table1Nam continue; } if(builder.length() > 0){ - builder.append(" and "); + builder.append(" or "); } - builder.append(String.format("%s.\"%s\"=%s.\"%s\"", - table1Name, column.getName(), table2Name, column.getName())); + builder.append(String.format("((%1$s.\"%2$s\" IS NOT NULL AND %3$s.\"%2$s\" IS NOT NULL AND %1$s.\"%2$s\"<>%3$s.\"%2$s\") or (%1$s.\"%2$s\" IS NULL AND %3$s.\"%2$s\" IS NOT NULL) or (%1$s.\"%2$s\" IS NOT NULL AND %3$s.\"%2$s\" IS NULL))", + table1Name, column.getName(), table2Name)); } - return "not (" + builder.toString() + ")"; + return "(" + builder.toString() + ")"; } private String buildNonLobColumnsString(Table table){ From a145dd12b03bf842d5b5a3c06bc34caf4bdbe599 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Lukas=20W=C3=B6hrl?= Date: Thu, 7 Apr 2016 21:10:52 +0200 Subject: [PATCH 5/5] apply changes from upstream branch and exclude only non comparable columns --- .../db/mssql/MsSqlTriggerTemplate.java | 58 +++++++++++++++---- 1 file changed, 46 insertions(+), 12 deletions(-) diff --git a/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java b/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java index f4c25b28c0..bb52de2fbd 100644 --- a/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java +++ b/symmetric-client/src/main/java/org/jumpmind/symmetric/db/mssql/MsSqlTriggerTemplate.java @@ -20,8 +20,12 @@ */ package org.jumpmind.symmetric.db.mssql; +import static org.apache.commons.lang.StringUtils.isBlank; +import static org.apache.commons.lang.StringUtils.isNotBlank; + import java.util.HashMap; +import org.apache.commons.lang.StringUtils; import org.jumpmind.db.model.Column; import org.jumpmind.db.model.Table; import org.jumpmind.symmetric.common.ParameterConstants; @@ -31,6 +35,7 @@ import org.jumpmind.symmetric.model.Channel; import org.jumpmind.symmetric.model.Trigger; import org.jumpmind.symmetric.model.TriggerHistory; +import org.jumpmind.symmetric.util.SymmetricUtils; import org.jumpmind.util.FormatUtils; public class MsSqlTriggerTemplate extends AbstractTriggerTemplate { @@ -41,7 +46,9 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { boolean castToNVARCHAR = symmetricDialect.getParameterService().is(ParameterConstants.MSSQL_USE_NTYPES_FOR_SYNC); String triggerExecuteAs = symmetricDialect.getParameterService().getString(ParameterConstants.MSSQL_TRIGGER_EXECUTE_AS, "self"); - + + String defaultCatalog = symmetricDialect.getParameterService().is(ParameterConstants.MSSQL_INCLUDE_CATALOG_IN_TRIGGERS, true) ? "$(defaultCatalog)" : ""; + // @formatter:off emptyColumnTemplate = "''" ; stringColumnTemplate = "case when $(tableAlias).\"$(columnName)\" is null then '' else '\"' + replace(replace(convert("+ @@ -52,8 +59,8 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { numberColumnTemplate = "case when $(tableAlias).\"$(columnName)\" is null then '' else ('\"' + convert(varchar(40), $(tableAlias).\"$(columnName)\",2) + '\"') end" ; datetimeColumnTemplate = "case when $(tableAlias).\"$(columnName)\" is null then '' else ('\"' + convert(varchar,$(tableAlias).\"$(columnName)\",121) + '\"') end" ; clobColumnTemplate = "case when $(origTableAlias).\"$(columnName)\" is null then '' else '\"' + replace(replace(cast($(origTableAlias).\"$(columnName)\" as "+(castToNVARCHAR ? "n" : "")+"varchar(max)),'\\','\\\\'),'\"','\\\"') + '\"' end" ; - blobColumnTemplate = "case when $(origTableAlias).\"$(columnName)\" is null then '' else '\"' + replace(replace($(defaultCatalog)dbo.sym_base64_encode(CONVERT(VARBINARY(max), $(origTableAlias).\"$(columnName)\")),'\\','\\\\'),'\"','\\\"') + '\"' end" ; - binaryColumnTemplate = "case when $(tableAlias).\"$(columnName)\" is null then '' else '\"' + replace(replace($(defaultCatalog)dbo.sym_base64_encode(CONVERT(VARBINARY(max), $(tableAlias).\"$(columnName)\")),'\\','\\\\'),'\"','\\\"') + '\"' end" ; + blobColumnTemplate = "case when $(origTableAlias).\"$(columnName)\" is null then '' else '\"' + replace(replace($(defaultCatalog)dbo.$(prefixName)_base64_encode(CONVERT(VARBINARY(max), $(origTableAlias).\"$(columnName)\")),'\\','\\\\'),'\"','\\\"') + '\"' end" ; + binaryColumnTemplate = "case when $(tableAlias).\"$(columnName)\" is null then '' else '\"' + replace(replace($(defaultCatalog)dbo.$(prefixName)_base64_encode(CONVERT(VARBINARY(max), $(tableAlias).\"$(columnName)\")),'\\','\\\\'),'\"','\\\"') + '\"' end" ; booleanColumnTemplate = "case when $(tableAlias).\"$(columnName)\" is null then '' when $(tableAlias).\"$(columnName)\" = 1 then '\"1\"' else '\"0\"' end" ; triggerConcatCharacter = "+" ; newTriggerValue = "inserted" ; @@ -74,10 +81,10 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " select @TransactionId = convert(VARCHAR(1000),transaction_id) from sys.dm_exec_requests where session_id=@@SPID and open_transaction_count > 0 \n" + " end \n" + " if ($(syncOnIncomingBatchCondition)) begin \n" + -" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data \n" + +" insert into " + defaultCatalog + "$(defaultSchema)$(prefixName)_data \n" + " (table_name, event_type, trigger_hist_id, row_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + " select '$(targetTableName)','I', $(triggerHistoryId), $(columns), \n" + -" $(channelExpression), $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp \n" + +" $(channelExpression), $(txIdExpression), " + defaultCatalog + "dbo.$(prefixName)_node_disabled(), $(externalSelect), current_timestamp \n" + " $(if:containsBlobClobColumns) \n" + " from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) \n" + " $(else:containsBlobClobColumns) \n" + @@ -101,9 +108,9 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " select @TransactionId = convert(VARCHAR(1000),transaction_id) from sys.dm_exec_requests where session_id=@@SPID and open_transaction_count > 0 \n" + " end \n" + " if ($(syncOnIncomingBatchCondition)) begin \n" + -" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, row_data, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + +" insert into " + defaultCatalog + "$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, row_data, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + " select '$(targetTableName)','U', $(triggerHistoryId), $(columns), $(oldKeys), $(oldColumns), $(channelExpression), "+ -" $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp\n" + +" $(txIdExpression), " + defaultCatalog + "dbo.$(prefixName)_node_disabled(), $(externalSelect), current_timestamp\n" + " $(if:containsBlobClobColumns) \n" + " from inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) inner join deleted on $(oldNewPrimaryKeyJoin) \n" + " $(else:containsBlobClobColumns) \n" + @@ -128,9 +135,9 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " select @TransactionId = convert(VARCHAR(1000),transaction_id) from sys.dm_exec_requests where session_id=@@SPID and open_transaction_count > 0 \n" + " end \n" + " if ($(syncOnIncomingBatchCondition)) begin \n" + -" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, row_data, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + +" insert into " + defaultCatalog + "$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, row_data, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + " select '$(targetTableName)','U', $(triggerHistoryId), $(columns), $(oldKeys), $(oldColumns), $(channelExpression), "+ -" $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp\n" + +" $(txIdExpression), " + defaultCatalog + "dbo.$(prefixName)_node_disabled(), $(externalSelect), current_timestamp\n" + " $(if:containsBlobClobColumns) \n" + " from (select $(nonBlobColumns), row_number() over (order by (select 1)) as __row_num from inserted) inserted inner join $(schemaName)$(tableName) $(origTableAlias) on $(tableNewPrimaryKeyJoin) inner join (select $(nonBlobColumns), row_number() over (order by (select 1)) as __row_num from deleted)deleted on (inserted.__row_num = deleted.__row_num)\n" + " $(else:containsBlobClobColumns) \n" + @@ -154,9 +161,9 @@ public MsSqlTriggerTemplate(ISymmetricDialect symmetricDialect) { " select @TransactionId = convert(VARCHAR(1000),transaction_id) from sys.dm_exec_requests where session_id=@@SPID and open_transaction_count > 0 \n" + " end \n" + " if ($(syncOnIncomingBatchCondition)) begin \n" + -" insert into $(defaultCatalog)$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + +" insert into " + defaultCatalog + "$(defaultSchema)$(prefixName)_data (table_name, event_type, trigger_hist_id, pk_data, old_data, channel_id, transaction_id, source_node_id, external_data, create_time) \n" + " select '$(targetTableName)','D', $(triggerHistoryId), $(oldKeys), $(oldColumns), $(channelExpression), \n" + -" $(txIdExpression), $(defaultCatalog)dbo.sym_node_disabled(), $(externalSelect), current_timestamp\n" + +" $(txIdExpression), " + defaultCatalog + "dbo.$(prefixName)_node_disabled(), $(externalSelect), current_timestamp\n" + " from deleted where $(syncOnDeleteCondition) \n" + " end \n" + " $(custom_on_delete_text) \n" + @@ -188,11 +195,38 @@ protected String replaceTemplateVariables(DataEventType dml, Trigger trigger, return ddl; } + private boolean isNotComparable(Column column){ + String columnType = column.getJdbcTypeName(); + return StringUtils.equalsIgnoreCase(columnType, "IMAGE") + || StringUtils.equalsIgnoreCase(columnType, "TEXT") + || StringUtils.equalsIgnoreCase(columnType, "NTEXT"); + } + + protected String getSourceTablePrefix(TriggerHistory triggerHistory) { + String prefix = (isNotBlank(triggerHistory.getSourceSchemaName()) ? SymmetricUtils.quote( + symmetricDialect, triggerHistory.getSourceSchemaName()) + symmetricDialect.getPlatform().getDatabaseInfo().getSchemaSeparator() : ""); + prefix = (isNotBlank(triggerHistory.getSourceCatalogName()) ? SymmetricUtils.quote( + symmetricDialect, triggerHistory.getSourceCatalogName()) + symmetricDialect.getPlatform().getDatabaseInfo().getCatalogSeparator() : "") + + prefix; + if (isBlank(prefix)) { + prefix = (isNotBlank(symmetricDialect.getPlatform().getDefaultSchema()) ? SymmetricUtils + .quote(symmetricDialect, symmetricDialect.getPlatform().getDefaultSchema()) + + "." : ""); + + if (symmetricDialect.getParameterService().is(ParameterConstants.MSSQL_INCLUDE_CATALOG_IN_TRIGGERS, true)) { + prefix = (isNotBlank(symmetricDialect.getPlatform().getDefaultCatalog()) ? SymmetricUtils + .quote(symmetricDialect, symmetricDialect.getPlatform().getDefaultCatalog()) + + "." : "") + prefix; + } + } + return prefix; + } + private String buildNonLobColumnsAreNotEqualString(Table table, String table1Name, String table2Name){ StringBuilder builder = new StringBuilder(); for(Column column : table.getColumns()){ - boolean isLob = symmetricDialect.getPlatform().isLob(column.getMappedTypeCode()); + boolean isLob = isNotComparable(column); if(isLob || column.isPrimaryKey()){ continue;