이 문서에서는 커밋 타임스탬프 기능을 사용하여 데이터베이스 레코드가 변경된 날짜와 시간을 추적하는 방법을 설명합니다. 레코드를 변경하는 트랜잭션이 많은 대규모 데이터베이스가 있고 데이터 세트의 변경사항을 캡처하려는 경우 커밋 타임스탬프 기능으로 이 작업을 간소화할 수 있습니다.
이 문서에서는 일련의 코드 샘플을 통해 기존 데이터 조작 언어(DML)를 다시 작성하여 변경 로그를 만드는 방법을 보여줍니다. 이 문서는 Cloud Spanner 커밋 타임스탬프를 사용하여 Go로 변경 로그 만들기에서 더 나아가 Java 및 JDBC를 사용하는 메서드를 설명합니다. 로직은 Spanner 클라이언트 객체가 아닌 SQL로 표현됩니다.
테이블 작동 방식
msgs라는 사실 테이블과 msg_history라는 기록 테이블이 있다고 가정하겠습니다. 사실 테이블이 수정될 때마다 레코드를 msg_history 테이블에 동시에 저장하려고 합니다. 나중에 감사 또는 이벤트 소스와 같은 다른 용도로 기록 테이블의 콘텐츠를 사용할 수 있습니다.
msgs 테이블에는 트랜잭션 ID(id)와 메시지(msg)로 표현되는 사실이 포함됩니다. 테이블을 만드는 데 사용되는 데이터 정의 언어(DDL) 문은 다음과 같습니다.
사실 테이블에만 기록하지 않고 동일한 트랜잭션의 기록 테이블에 작업을 수행해야 합니다. Spanner의 JDBC 드라이버는 표준 JDBC 작업인 트랜잭션의 시작과 끝 선언을 지원합니다.
1단계: 삽입 작업 재작성
첫 번째 단계는 다음 양식에서 insert 작업을 다시 작성하는 것입니다.
insertintomsgs(id,msg)values(1,'a real msg')
다음과 같이 삽입을 변경합니다.
insertintomsgs_history(id,previous_msg,ts)values(1,Null,PENDING_COMMIT_TIMESTAMP());insertintomsgs(id,msg)values(1,'a real msg');
자바 코드는 다음과 같습니다.
// insert into historystmt.executeUpdate("insert into msgs_history (id, previous_msg, ts)"+" values (1, Null, PENDING_COMMIT_TIMESTAMP())");// insert into real tablestmt.executeUpdate("insert into msgs (id, msg)"+" values (1, 'a real msg')");conn.commit();
// insert into historystmt.executeUpdate("insert msgs_history (id, previous_msg, ts)"+" values ((select id from msgs where id =1),"+" (select msg from msgs where id = 1), PENDING_COMMIT_TIMESTAMP())");// update into fact tablestmt.executeUpdate("update msgs set msg = 'new message' where id = 1");conn.commit();
// insert into historystmt.executeUpdate("insert msgs_history (id, previous_msg, ts)"+" values ((select id from msgs where id =1),"+" (select msg from msgs where id = 1), PENDING_COMMIT_TIMESTAMP()) ");// delete from real tablestmt.executeUpdate("delete from msgs where id = 1");conn.commit();
[[["이해하기 쉬움","easyToUnderstand","thumb-up"],["문제가 해결됨","solvedMyProblem","thumb-up"],["기타","otherUp","thumb-up"]],[["이해하기 어려움","hardToUnderstand","thumb-down"],["잘못된 정보 또는 샘플 코드","incorrectInformationOrSampleCode","thumb-down"],["필요한 정보/샘플이 없음","missingTheInformationSamplesINeed","thumb-down"],["번역 문제","translationIssue","thumb-down"],["기타","otherDown","thumb-down"]],["최종 업데이트: 2025-09-05(UTC)"],[],[],null,["# Create a change log with JDBC using the Spanner commit timestamp feature\n\nThis document describes how to use the\n[commit timestamp feature](/spanner/docs/commit-timestamp)\nto track the date and time when changes are made to your database records. When\nyou have a large database with many transactions that change records and you\nwant to capture changes made to the datasets, the commit timestamp feature\nsimplifies this task.\n\nThrough a series of code samples, this document shows you how to rewrite\nexisting data manipulation language (DML) to create a change log. The document\nextends [Using Cloud Spanner commit timestamps to create a change log with Go](/community/tutorials/cloud-spanner-commit-timestamp-change-log)\nby demonstrating the methods using Java and JDBC. The logic is represented in\nSQL rather than as Spanner client objects.\n| **Note:** An alternative to the solutions proposed on this page is Spanner change streams. Spanner change streams watch and stream out a Spanner database's data changes to other services. For more information, see [About change streams](/spanner/docs/change-streams).\n\nHow the tables work\n-------------------\n\nAssume you have a facts table called `msgs` and a history table called\n`msg_history`. Each time the facts table gets modified, you want to concurrently\nsave a record in the `msg_history` table. You can use the contents of the\nhistory table later for other uses---for example, for auditing or as an event\nsource.\n\nThe `msgs` table holds the facts, represented by a transaction ID (`id`) and\nthe message (`msg`). The data definition language (DDL) statement that you use\nto create the table looks like the following: \n\n CREATE TABLE msgs (\n id INT64,\n msg STRING(MAX),\n ) PRIMARY KEY (id)\n\nThe `msg_history` table holds the transaction history. The following DDL\ncreates the history table. The column `ts` stores the commit timestamp. \n\n CREATE TABLE msgs_history (\n id INT64,\n ts TIMESTAMP OPTIONS (allow_commit_timestamp=true),\n previous_msg STRING(MAX)\n ) PRIMARY KEY (ts, id)\n\n### The examples\n\nInstead of writing only to the facts table, you must do the operation to the\nhistory table in the same transaction. Spanner's JDBC driver\nsupports declaration of the start and end of a transaction, which is a standard\nJDBC operation.\n\n#### Step 1: Rewrite the insert operations\n\nThe first step is to rewrite the `insert` operations from the following form: \n\n insert into msgs (id, msg) values (1, 'a real msg')\n\n- Change the inserts to look like the following:\n\n insert into msgs_history (id, previous_msg, ts) values (1, Null, PENDING_COMMIT_TIMESTAMP());\n insert into msgs (id, msg) values (1, 'a real msg');\n\n Here's the Java code: \n\n // insert into history\n stmt.executeUpdate(\n \"insert into msgs_history (id, previous_msg, ts)\"\n + \" values (1, Null, PENDING_COMMIT_TIMESTAMP())\");\n // insert into real table\n stmt.executeUpdate(\"insert into msgs (id, msg)\" + \" values (1, 'a real msg')\");\n conn.commit();\n\n#### Step 2: Rewrite the update operations\n\nNext, you rewrite the `update` operations from the following form: \n\n update msgs set msg = 'new message' where id = 1\n\n- Change the updates to look like the following:\n\n insert msgs_history (id, previous_msg, ts) values ((select id from msgs where id =1 ), (select msg from msgs where id = 1), PENDING_COMMIT_TIMESTAMP());\n update msgs set msg = 'new message' where id = 1;\n\n Here's the Java code: \n\n // insert into historystmt.executeUpdate(\n \"insert msgs_history (id, previous_msg, ts)\"\n + \" values ((select id from msgs where id =1),\"\n + \" (select msg from msgs where id = 1), PENDING_COMMIT_TIMESTAMP())\");\n // update into fact table\n stmt.executeUpdate(\"update msgs set msg = 'new message' where id = 1\");\n conn.commit();\n\n#### Step 3: Rewrite the delete operations\n\nFinally, you rewrite the `delete` operations from the following form: \n\n delete from msgs where id = 1\n\n- Change the deletes to look like the following:\n\n insert msgs_history (id, previous_msg, ts) values ((select id from msgs where id =1 ), (select msg from msgs where id = 1), PENDING_COMMIT_TIMESTAMP());\n delete from msgs where id = 1;\n\n Here's the Java code: \n\n // insert into history\n stmt.executeUpdate(\n \"insert msgs_history (id, previous_msg, ts)\"\n + \" values ((select id from msgs where id =1),\"\n + \" (select msg from msgs where id = 1), PENDING_COMMIT_TIMESTAMP()) \");\n // delete from real table\n stmt.executeUpdate(\"delete from msgs where id = 1\");\n conn.commit();\n\n### Using the history table\n\n- Access the change history as follows:\n\n select id,msg,current_timestamp() as ts\n from msgs where id = 1\n union all\n select id,previous_msg, ts as msg\n from msgs_history where id = 1 order by ts desc\n\n The results look similar to the following: \n\n ```\n id msg ts\n 1 new message 2020-02-07T07:44:10.24833726Z\n 1 a real msg 2020-01-14T10:07:20.137935Z\n 1 2020-01-14T10:07:20.070374Z\n ```\n\nWhat's next\n-----------\n\n- Read more about the [Spanner commit timestamp feature](/spanner/docs/commit-timestamp).\n- Learn more about [Spanner change streams](/spanner/docs/change-streams).\n- Explore reference architectures, diagrams, and best practices about Google Cloud. Take a look at our [Cloud Architecture Center](/architecture)."]]