A bit wiser with Oracle technology

Learn how to use a metadata repository to identify a "source of truth" for each customer attribute in a data warehouse. This tip explains how to use the base-two numbering values of the primary key in the data source reference table and bitwise logical operations within the Oracle database to denormalize the one-to-many relationship between a customer and its data sources.

It was Thanksgiving morning and Shannon, an architect at ABC Gum Company, was thinking about getting home and eating her turkey dinner when she received an email. The email was a request from the data warehouse team for a table design which would store a complete customer record in a single row. The email went on to say that internal audit had mandated data controls around each attribute and record. Oh, one more thing -- they needed...

it today!

Fortunately Shannon's company had implemented an information strategy which allowed for a 360-degree view of a customer. She knew the customer attributes that were shared across the enterprise were centrally located, and the remaining attributes were stored locally with each system. In fact, Shannon had helped design a federated customer data model within the corporate metadata repository just days before, which described these attributes and their relationships. With the customer information taken care of, Shannon thought about how she would apply data controls.

She again turned to the metadata repository to help her identify a system of record for each customer attribute. She smiled to herself, remembering her design sessions where she had told her fellow architects, "A 'source of truth' for each attribute will come in handy someday." She also needed to store a rollup "source of truth" for the aggregate row. Again, Shannon had the answer; she would use the base-two numbering values of the primary key in the data source reference table and bitwise logical operations within the Oracle database to denormalize the one-to-many relationship between a customer and its data sources. She could store this value in one column for each row.

Binary numbers

Binary numbers (base two) are most commonly represented as Arabic numeral symbols 0 and 1. Binary numbers are in fact a sequence of bits with each bit representing one of two values.

The following charts show the decimal (base 10) number 13 (10+3) and its equivalent binary, base 2, number 1101 (8+4+1).

 

10000

1000

100

10

1

Base 10 Numeral

 

 

 

1

3

 

16

8

4

2

1

Base 2 Numeral

 

1

1

0

1

Bitwise logical operations

When bits are manipulated by Boolean logical operators, it is referred to as a bitwise operation. A bitwise operation operates on two-bit patterns of equal lengths by positionally matching their individual bits.

AND
A logical AND of each bit pair results in a 1 if the first bit is 1 AND the second bit is 1. Otherwise the result is zero.

OR
A logical OR of each bit pair results in a 1 if the first bit is 1 OR the second bit is 1. Otherwise, the result is zero.

XOR
A logical XOR of each bit pair results in a 1 if the two bits are different, and 0 if they are the same.

Bitwise Logical Operations

Bit One

Bit Two

AND

OR

XOR

0

0

0

0

0

0

1

0

1

1

1

0

0

1

1

1

1

1

1

0

The central database contained a data source reference table which looked something like this:

create table val_data_source
   (data_source_id         number(9)     not null
   ,data_source_name       varchar2(30)  not null
   .
   .
   .
   ,constraint val_data_source_pk primary key (data_source_id)
   );
   
Data Source     Data Source ID  Base 2 Representation
------------    --------------  ---------------------
CUSTOMER         1              00001
MARKETING        2              00010
SALES            4              00100
CLAIMS           8              01000
SERVICE         16              10000

Shannon now began to design the customer table. For each customer column, she added a <column>_sot to store the "source of truth" for each attribute. She added a column called data_source_sot, to aggregate the "sources of truth" for each customer.

create table customer
   (cutomer_id                  number(12)   not null
   ,data_source_sot             number(2)    not null
   ,customer_name               varchar2(80)     null
   ,customer_name_sot           number(2)        null   
   ,territory                   varchar2(30)     null
   ,territory_sot               number(2)        null 
   ,total_sales                 number(12,2)     null
   ,total_premium_sot           number(2)        null  
   ,total_claim                 number(12,2)     null  
   ,total_claim_sot             number(2)        null 
   );

Sample Data:

cutomer_id   : 1000000000 
data_source_sot   : 13 
customer_name     : National Gum Distributors 
customer_name_sot : 1
territory         : null 
territory_sot     : null 
total_sales      : $100.00 
total_premium_sot : 4 
total_claim       : $25.50
total_claim_sot : 8

By adding the values of the data source primary keys she could store one value and use a "bitand" operation to query the column. For example, a row consisting of aggregating data from data sources; CUSTOMER, SALES and CLAIMS would have a value of 13 (1 + 4 + 8) in the data_source_sot column.

BITAND

Syntax

bitand::=

BITAND computes an AND operation on the bits of expr1 and expr2, both of which must resolve to nonnegative integers, and returns an integer.

Reference: Oracle Database SQL Reference 10g Release 1 (10.1)

Users could query the single column to determine a row's "source of truth." If the "bitand" operation was successful then the value of the data_source_id (expr2) would be returned else 0.

Here we see the customer record has data from the SALES system.

select bitand(data_source_sot,4) 
  from customer 
  where customer_name = 'National Gum Distributors';

Data Source ID
--------------
             4

This function is commonly used with the DECODE function, as illustrated in the example that follows:

select  decode(bitand(data_source_sot,1) , 1,'CUSTOMER ' ,NULL) 
      ||decode(bitand(data_source_sot,2) , 2,'MARKETING ',NULL)
      ||decode(bitand(data_source_sot,4) , 4,'SALES '    ,NULL)
      ||decode(bitand(data_source_sot,8) , 8,'CLAIMS '   ,NULL)
      ||decode(bitand(data_source_sot,16),16,'SERVICE'   ,NULL)
      "Data Sources"
  from customer 
  where customer_name = 'National Gum Distributors';  
  
Data Sources
-------------------------------------------
CUSTOMER SALES CLAIMS

The following is a partial table showing the relationship between data sources and rollup values:

01  CUSTOMER
02  MARKETING
03  CUSTOMER,MARKETING
04  SALES
05  CUSTOMER,SALES
06  MARKETING,SALES
07  CUSTOMER,MARKETING,SALES
08  CLAIMS
09  CUSTOMER,CLAIMS
10  MARKETING,CLAIMS
11  CUSTOMER,MARKETING,CLAIMS
12  SALES,CLAIMS
13  CUSTOMER,SALES,CLAIMS
14  MARKETING,SALES,CLAIMS
15  CUSTOMER,MARKETING,SALES,CLAIMS
16  SERVICE
.
.
.
31  CUSTOMER,MARKETING,SALES,CLAIMS,SERVICE

Next, Shannon decided to extend Oracle's bitwise functionality by coding OR and XOR functions.

Additional Bitwise Functions

OR

create function bitor (exp1 number, exp2 number)
return number
is
begin
  return ((exp1 + exp2) - bitand(exp1,exp2));
end;

XOR

create function bitxor (exp1 number, exp2 number)
return number
is
begin
  return ((exp1 + exp2) - bitand(exp1,exp2) * 2);
end;

Reference: http://asktom.oracle.com, Tom Kyte

Glancing at the clock, Shannon sent her design to the data warehouse team as she felt a grumble in her stomach. Just then an announcement came over the speaker wishing everyone a Happy Thanksgiving. It was time to go home. Later, as Shannon sat down to dinner with her family, she reflected on the importance of the information strategy, data architecture and Oracle bitwise technology. "This was a good day," she thought, "I have much to be grateful for."

About the author

Jeff McCormick is a senior data architect at a financial services company and executive director of the Connecticut Oracle User Group. Jeff has worked in IT for almost 20 years as a system, storage and database architect/administrator and has over 15 years of experience with DB2, Sybase, SQL Server, MySQL and Oracle relational database technology. He holds several certifications including Oracle Database 10g Administrator Certified Professional, Microsoft Certified Product (SQL Server) and Certified Sybase Professional Database Administrator. Jeff has performed extensive work in the area of high availability and disaster recovery, speaking and authoring several papers on availability architecture.

This was first published in October 2006

Dig deeper on Oracle DBA jobs, training and certification

Pro+

Features

Enjoy the benefits of Pro+ membership, learn more and join.

0 comments

Oldest 

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to:

-ADS BY GOOGLE

SearchDataManagement

SearchBusinessAnalytics

SearchSAP

SearchSQLServer

TheServerSide

SearchDataCenter

SearchContentManagement

SearchFinancialApplications

Close