Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

How to Use BINARY_CHECKSUM operation. Expand / Collapse
Author
Message
Posted Wednesday, December 22, 2010 10:51 AM


Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Wednesday, December 26, 2012 11:03 PM
Points: 586, Visits: 2,195
Hi

How to do this

GO
CREATE TABLE #myTable (column1 int, column2 varchar(256));
go
CREATE TABLE #myTable_hist (column1 int, column2 varchar(256));
GO
INSERT INTO #myTable VALUES (1, 'test');
INSERT INTO #myTable VALUES (2, 'test');
--SELECT BINARY_CHECKSUM(*) from #myTable;

INSERT INTO #myTable_hist
Select * from #myTable
--SELECT BINARY_CHECKSUM(*) from #myTable;

INSERT INTO #myTable VALUES (3, 'test');
--- BINARY_CHECKSUM Need to check whether 3rd value is there are not in his table if not there then need to insert 3rd value alone
-- Will be able to check with BINARY_CHECKSUM row by row checking changes are there or not with the previous records
---Flag like condition for row by row processing
INSERT INTO #myTable_hist
Select * from #myTable

GO
Drop TABLE #myTable
go
Drop TABLE #myTable_hist


Thanks
Parthi


Thanks
Parthi
Post #1038399
Posted Wednesday, December 22, 2010 11:07 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: 2 days ago @ 10:10 AM
Points: 292, Visits: 1,615
This should help get you going:
CREATE TABLE #myTable (column1 int, column2 varchar(256));
go
CREATE TABLE #myTable_hist (column1 int, column2 varchar(256), HistCheck INT);
GO
INSERT INTO #myTable VALUES (1, 'test');
INSERT INTO #myTable VALUES (2, 'test');

INSERT #myTable_hist (column1, column2, HistCheck)
Select column1, column2, CHECKSUM(column2) from #myTable

-- Add new row
INSERT INTO #myTable VALUES (3, 'test');

WITH cte
AS
(
SELECT *, CHECKSUM(Column2) AS CheckVal
FROM #myTable
)

MERGE
#myTable_hist AS Target
USING
cte AS Source
ON Target.column1 = Source.column1
WHEN MATCHED AND (Target.HistCheck <> Source.CheckVal) THEN
UPDATE SET
Target.Column2 = Source.Column2,
Target.HistCheck = Source.CheckVal
WHEN NOT MATCHED THEN
INSERT (column1, column2, HistCheck)
VALUES (Source.column1, Source.column2, Source.CheckVal);

Post #1038406
Posted Wednesday, December 22, 2010 11:21 AM


Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Wednesday, December 26, 2012 11:03 PM
Points: 586, Visits: 2,195

Hi
Thanks for your query with Merge join New thing learned today on this.i have heared on this but not worked with data but now it also has been done so again spl thanks.

update #myTable set column2='TEST' where column1=2
If we use CHECKSUM then it does not check the above thing i have changed column2 as UPPER Case.It will be work in BINARY_CHECKSUM

If i update column2='TESTS' then it works
update #myTable set column2='TESTS' where column1=2

This is fine.But there is change in the string to UPPER Case which also need to be tracked must be updated in #myTable_hist Table how can we do this


Thanks
Parthi


Thanks
Parthi
Post #1038414
Posted Wednesday, December 22, 2010 11:56 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: 2 days ago @ 10:10 AM
Points: 292, Visits: 1,615
Well it appears that you have a case insensitive collation, so CHECKSUM won't show a difference between the same word with different cased letters. Just as if you did it in SQL; 'test' = 'TEST'.

If you need to make that sort of update there are several options. One option is to COLLATE your strings to something Case Sensitive before applying the CHECKSUM function. Another option is to use the BINARY_CHECKSUM function (updating your checksum columns type appropriately). There are other options, but those are probably the easiest.
Post #1038427
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse