Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to Use BINARY_CHECKSUM operation.


How to Use BINARY_CHECKSUM operation.

Author
Message
parthi-1705
parthi-1705
SSChasing Mays
SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)

Group: General Forum Members
Points: 602 Visits: 2196
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
Lamprey13
Lamprey13
Old Hand
Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)

Group: General Forum Members
Points: 304 Visits: 1657
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);


parthi-1705
parthi-1705
SSChasing Mays
SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)SSChasing Mays (602 reputation)

Group: General Forum Members
Points: 602 Visits: 2196
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
Lamprey13
Lamprey13
Old Hand
Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)Old Hand (304 reputation)

Group: General Forum Members
Points: 304 Visits: 1657
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.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search