Oracle BLOCKCHAIN TABLES
Version 21c

General Information
Library Note Morgan's Library Page Header
Which has the higher priority in your organization: Deploying a new database or securing the ones you already have? Looking for a website, and resources, dedicated solely to securing Oracle databases? Check out DBSecWorx.
Be sure to view the full listing of monographs in Morgan's Library
Purpose Blockchain tables are intended to provide an extremely tamper resistant means of storing relational data in a form wherein it can be accessed using SQL. Blockchain tables intended for use in an environment where it is required that the ledger be distributed to multiple organizations/locations, but clearly that distribution is possible if one considers integration with data distribution tools such as Data Guard and GoldenGate.
Data Dictionary Objects
ALL_SEGMENTS CDB_TAB_COLS DBA_TABLES
ALL_TAB_COLS CDB_TABLES USER_SEGMENTS
ALL_TABLES DBA_SEGMENTS USER_TAB_COLS
CDB_SEGMENTS DBA_TAB_COLS USER_TABLES
Exceptions
Error Code Reason
ORA-05729 blockchain table cannot be created in root container
First Available 20c
System Privileges
ALTER ANY TABLE CREATE ANY TABLE DROP ANY TABLE
ALTER TABLE CREATE TABLE DROP TABLE
 
General (new 20c)
Block Change table CREATE BLOCKCHAIN TABLE <schema_name>.<table_name>(
<column_name> <column_data_type>)
NO DROP [UNTIL <integer> DAYS IDLE]
HASHING USING "<hashing_algorithm>" VERSION "<version_number>"
[sharing_clause]
[memoptimize_clause]
[relational_properties];
CREATE BLOCKCHAIN TABLE uwclass.ledger1(
tx_id INTEGER,
tx_date DATE,
tx_value NUMBER(10,2))
NO DROP UNTIL 31 DAYS IDLE
NO DELETE UNTIL 31 DAYS AFTER INSERT
HASHING USING "SHA2_512" VERSION "v1"
TABLESPACE uwdata;
Block Change table with LOCKED CREATE BLOCKCHAIN TABLE <schema_name>.<table_name>(
<column_name> <column_data_type>)
NO DROP [UNTIL <integer> DAYS IDLE]
NO DELETE UNTIL <integer> DAYS AFTER INSERT [LOCKED]
HASHING USING "<hashing_algorithm>" VERSION "<version_number>"
[sharing_clause]
[memoptimize_clause]
[relational_properties];
CREATE BLOCKCHAIN TABLE uwclass.ledger2(
tx_id INTEGER,
tx_date DATE,
tx_value NUMBER(10,2))
NO DROP UNTIL 31 DAYS IDLE
NO DELETE UNTIL 90 DAYS AFTER INSERT LOCKED
HASHING USING "SHA2_512" VERSION "v1"
TABLESPACE uwdata;
Block Chain table with range partitioning

This was enabled in 20c but is not available in 21.1.
CREATE BLOCKCHAIN TABLE <schema_name>.<table_name>(
<column_name> <column_data_type>)
NO DROP UNTIL
NO DELETE LOCKED
HASHING USING "<hashing_algorithm>" VERSION "<version_number>"
PARTITION BY ....;
CREATE BLOCKCHAIN TABLE uwclass.ledger_partitioned(
tx_id     NUMBER,
tx_date   DATE,
grantor   VARCHAR2(60),
grantee   VARCHAR2(60))
NO DROP UNTIL 60 DAYS IDLE
NO DELETE UNTIL 31 DAYS AFTER INSERT
HASHING USING "SHA2_512" VERSION "v1"
PARTITION BY RANGE
(trans_date) (
 PARTITION p1 VALUES LESS THAN (TO_DATE('01-01-2018','dd-mm-yyyy')),
 PARTITION p2 VALUES LESS THAN (TO_DATE('01-01-2019','dd-mm-yyyy')),
 PARTITION p3 VALUES LESS THAN (TO_DATE('01-01-2020','dd-mm-yyyy')),
 PARTITION p4 VALUES LESS THAN (TO_DATE('01-01-2021','dd-mm-yyyy')));
CREATE BLOCKCHAIN TABLE uwclass.ledger_partitioned(
*
ERROR at line 1:
ORA-00439: feature not enabled: Partitioning
Create Blockchain Table Reverse Engineered -- reformatted for legibility

SELECT dbms_metadata.get_ddl('TABLE', 'LEDGER2','UWCLASS') FROM dual;

CREATE BLOCKCHAIN TABLE "UWCLASS"."LEDGER2" (
 "TX_ID"   NUMBER(*,0),
 "TX_DATE" DATE,
 "TX_VALUE" NUMBER(10,2))
SEGMENT CREATION DEFERRED
NO DROP UNTIL 31 DAYS IDLE
NO DELETE UNTIL 31 DAYS AFTER INSERT
HASHING USING "SHA2_512" VERSION "v1"
PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255
NOCOMPRESS LOGGING
TABLESPACE "USERS"
BEGIN
  -- insert chain$ rows
  -- insert epoch$ rows
  SYS.DBMS_BLOCKCHAIN_TABLE.IMPORT_EPOCH(
    SCHEMA_NAME => 'UWCLASS',
    TABLE_NAME => 'LEDGER2',
    EPOCH_NUM => 1,
    REASON_ID => 1,
    PDB_GUID => 'B6355315C77F2BECE0531000000A714D',
    HASH_ALGO => 1,
    HASH_FORMAT => 1);

  -- insert import epoch$ row
  SYS.DBMS_BLOCKCHAIN_TABLE.IMPORT_EPOCH(
    SCHEMA_NAME => 'UWCLASS',
    TABLE_NAME => 'LEDGER2',
    EPOCH_NUM => 2,
    REASON_ID => 2,
    PDB_GUID => NULL,
    HASH_ALGO => 1,
    HASH_FORMAT => 1);
END;

SELECT * FROM blockchain_table_chain$;

no rows selected

SELECT obj#, epoch#, pdb_guid
FROM blockchain_table_epoch$;

 OBJ# EPOCH# PDB_GUID
----- ------ ---------------------------------
76001      1 B6355315C77F2BECE0531000000A714D


SELECT obj#, hash_algorithm#, hash_data_format_version#, reason#
FROM blockchain_table_epoch$;

 OBJ# HASH_ALGORITHM# HASH_DATA_FORMAT_VERSION# REASON#
----- --------------- ------------------------- -------
76001               1                         1       1
 
BlockChain Table Demos
  conn / as sysdba

CREATE BLOCKCHAIN TABLE uwclass.ledger (
tx_id    INTEGER,
tx_date  DATE,
tx_value NUMBER(10,2))
NO DROP UNTIL 31 DAYS IDLE
NO DELETE LOCKED
HASHING USING "SHA2_512" VERSION "v1";
CREATE BLOCKCHAIN TABLE ledger (txn_id INTEGER, tx_date DATE, tx_value NUMBER(10,2))
*
ERROR at line 1:
ORA-05729: blockchain table cannot be created in root container


ALTER SESSION SET CONTAINER=PDBDEV;

CREATE BLOCKCHAIN TABLE uwclass.ledger(
tx_id INTEGER,
tx_date DATE,
tx_value NUMBER(10,2))
NO DROP UNTIL 31 DAYS IDLE
NO DELETE LOCKED
HASHING USING "SHA2_512" VERSION "v1";

Table created.

SQL> desc uwclass.ledger
Name                          Null?    Type
----------------------------- -------- --------------------
TX_ID                                  NUMBER(38)
TX_DATE                                DATE
TX_VALUE                               NUMBER(10,2)


SQL> SELECT column_id, column_name, data_type, hidden_column, virtual_column, user_generated
  2  FROM dba_tab_cols
  3  WHERE owner = 'UWCLASS'
  4  WHERE table_name = 'LEDGER'
  5* ORDER BY user_generated, column_id;

COLUMN_ID  COLUMN_NAME               DATA_TYPE                    HID VIR USE
---------- ------------------------- ---------------------------- --- --- ---
           ORABCTAB_SIGNATURE$       RAW                          YES NO  NO
           ORABCTAB_SIGNATURE_ALG$   NUMBER                       YES NO  NO
           ORABCTAB_SIGNATURE_CERT$  RAW                          YES NO  NO
           ORABCTAB_SPARE$           RAW                          YES NO  NO
           ORABCTAB_USER_NUMBER$     NUMBER                       YES NO  NO
           ORABCTAB_CREATION_TIME$   TIMESTAMP(6) WITH TIME ZONE  YES NO  NO
           ORABCTAB_HASH$            RAW                          YES NO  NO
           ORABCTAB_INST_ID$         NUMBER                       YES NO  NO
           ORABCTAB_CHAIN_ID$        NUMBER                       YES NO  NO
           ORABCTAB_SEQ_NUM$         NUMBER                       YES NO  NO
        1  TX_ID                     NUMBER                       NO  NO  YES
        2  TX_DATE                   DATE                         NO  NO  YES
        3  TX_VALUE                  NUMBER                       NO  NO  YES


INSERT INTO uwclass.ledger
(tx_id, tx_date, tx_value)
VALUES
(1, SYSDATE, 100);
COMMIT;

Commit complete.

SELECT * FROM uwclass.ledger;

 TX_ID     TX_DATE           TX_VALUE
------ -------------------- ---------
     1 30-DEC-2020 21:40:58       100


col ORABCTAB_CREATION_TIME$ format a40
col ORABCTAB_HASH$ format a130

SELECT orabctab_user_number$, orabctab_creation_time$, orabctab_inst_id$
FROM uwclass.ledger;

ORABCTAB_USER_NUMBER$ ORABCTAB_CREATION_TIME$                ORABCTAB_INST_ID$
--------------------- -------------------------------------- -----------------
                    0 30-DEC-20 09.41.15.962751 PM +00:00                    1


SELECT orabctab_chain_id$, orabctab_seq_num$
FROM uwclass.ledger;

ORABCTAB_CHAIN_ID$ ORABCTAB_SEQ_NUM$
------------------ -----------------
                28                 1


SELECT orabctab_hash$
FROM uwclass.ledger;

ORABCTAB_HASH$
--------------------------------------------------------------------------------------------------------------------------------
EDB342BB5A6D3DC4731AE30BEC65BEDA23EDE4655F73A6A0BA14B2BEBC580C7636AE400853181B934A15855EF3284E7A0D71C212368862A0000CE1DFF6514135


SELECT object_name, object_type
FROM dba_objects_ae
WHERE object_name = 'LEDGER';

OBJECT_NAME                    OBJECT_TYPE
------------------------------ -------------------------
LEDGER                         TABLE


SELECT object_name, object_type
FROM dba_objects_ae
WHERE owner = 'UWCLASS'
AND object_name = 'LEDGER';

OBJECT_TYPE
-------------------
TABLE


SELECT table_name, table_type
FROM dba_all_tables
WHERE owner = 'UWCLASS'
AND table_name = 'LEDGER';

TABLE_NAME      TABLE_TYPE
--------------- -------------------
LEDGER


SELECT segment_name, segment_type
FROM dba_segments
WHERE owner = 'UWCLASS'
AND segment_name = 'LEDGER';

SEGMENT_NAME                   SEGMENT_TYPE
------------------------------ ------------------
LEDGER                         TABLE


UPDATE ledger SET tx_value = 200;
UPDATE ledger SET tx_value = 200
*
ERROR at line 1:
ORA-05715: operation not allowed on the blockchain table


DELETE FROM ledger;
DELETE FROM ledger
*
ERROR at line 1:
ORA-05715: operation not allowed on the blockchain table


TRUNCATE TABLE ledger;
TRUNCATE TABLE ledger
*
ERROR at line 1:
ORA-05715: operation not allowed on the blockchain table
 
BlockChain Table Queries
Tim Hall's Query col schema_name format a30
col table_name format a30
col row_retention format a13
col row_retention_locked format a20
col table_inactivity_retention format a26
col hash_algorithm format a14

SELECT schema_name, table_name, row_retention, row_retention_locked,  table_inactivity_retention, hash_algorithm
FROM dba_blockchain_tables;

Related Topics
Built-in Functions
Built-in Packages
Database Security
DBMS_BLOCKCHAIN_TABLE
DBMS_BLOCKCHAIN_UTL
DBMS_TABLE_DATA
DBMS_USER_CERTS
Object Privileges
System Privileges
Tables
What's New In 19c
What's New In 20c-21c