DataSunrise Achieves AWS DevOps Competency Status in AWS DevSecOps and Monitoring, Logging, Performance

Made Yourself Data Masking

Made Yourself Data Masking

This article describes how to create a VIEW for viewing depersonalized data. The solution described here is based on a solution from this article (getting a random string out of the table).

The main purpose of data masking is to obfuscate the real data and make it unrecoverable. But it is not enough just to hide the real data. Very often it is necessary to make it looks as realistic as possible.

Such requirements emerge because data masking is used mostly for application testing and the data should look like as realistic as it possible. And a good solution for this is to use the data from the actual table but take it from random rows.

Let’s begin.

I will use a table named “connections” for an example. This table includes “ID” and “client_port” columns which should be masked. And the “ID” column is the table’s primary key.

Since some rows could be deleted and ID contains not a strictly consistent value, let’s create a table with data linked with row number. Essentially, it is the quickest way for PostgreSQL to select data by the row number. If you’re using Oracle database, you can skip this step.

create table client_port_ids
	    (
	    rowid serial PRIMARY KEY,
	    id integer
	    );
	-- filling the table with existing id numbers. the table should be filled before masking
	INSERT INTO client_port_ids (id ) SELECT id FROM connections ORDER BY id;

Since you would like the database to show the same values at the masked row at every SELECT query, it is necessary to create a table to store the link between the real data and substitute.

create table client_port_map
	    (
	    src integer PRIMARY KEY,
	     dst integer
	    );

Let’s create a masking function to test if the masked data haven’t fetched before. And if this data is absent, the function takes the data from a random row.

CREATE OR REPLACE FUNCTION public.hide_client_port(
	val integer)
	RETURNS integer AS
	$BODY$
	DECLARE
	res integer;
	sed float;
	row_count integer;
	rand_row integer;
	BEGIN
	--check existing mapping
	SELECT dst into res FROM client_port_map WHERE src = val;
	IF FOUND = FALSE THEN
	--search random string
	select MAX(rowid) into row_count from client_port_ids;
	LOOP
	SELECT floor(random()*row_count) into rand_row;
	select client_port into res from connections where id = (select id from client_port_ids where rowid = rand_row);
	EXIT WHEN FOUND = TRUE;
	END LOOP;
	--saving new value to mapping
	INSERT INTO client_port_map VALUES (val, res);
	END IF;
	return res ;
	END;
	$BODY$
	LANGUAGE plpgsql VOLATILE

Let’s see how the entries are shuffled.

Since in this example we use a small table, some replaced entries match the real entries. That’s because it’s impossible to cheat the probability theory.

How this could be used? Let’s create a new schema with a VIEW using a table with real data. And for the “connections” table we create the following VIEW:

CREATE OR REPLACE VIEW public.connection AS
	SELECT connections.partition_id,
	connections.id,
	connections.interface_id,
	connections.client_host,
	hide_client_port(connections.client_port) AS hide_client_port,
	connections.begin_time,
	connections.end_time,
	connections.client_host_name,
	connections.instance_id,
	connections.proxy_id,
	connections.sniffer_id
	FROM connections;

As you see, it’s pretty easy. Of course, this function can be improved. For example, you could employ a mechanism to assign different values to rows that contain similar values. But it’s a whole new ball game.

To mask your data professionally you can use Dynamic Data Masking included in Data Sunrise Database Security Suite.

Next

How to Install the MySQL ODBC Driver on Ubuntu 16.04?

How to Install the MySQL ODBC Driver on Ubuntu 16.04?

Learn More

Need Our Support Team Help?

Our experts will be glad to answer your questions.

Countryx
United States
United Kingdom
France
Germany
Australia
Afghanistan
Islands
Albania
Algeria
American Samoa
Andorra
Angola
Anguilla
Antarctica
Antigua and Barbuda
Argentina
Armenia
Aruba
Austria
Azerbaijan
Bahamas
Bahrain
Bangladesh
Barbados
Belarus
Belgium
Belize
Benin
Bermuda
Bhutan
Bolivia
Bosnia and Herzegovina
Botswana
Bouvet
Brazil
British Indian Ocean Territory
Brunei Darussalam
Bulgaria
Burkina Faso
Burundi
Cambodia
Cameroon
Canada
Cape Verde
Cayman Islands
Central African Republic
Chad
Chile
China
Christmas Island
Cocos (Keeling) Islands
Colombia
Comoros
Congo, Republic of the
Congo, The Democratic Republic of the
Cook Islands
Costa Rica
Cote D'Ivoire
Croatia
Cuba
Cyprus
Czech Republic
Denmark
Djibouti
Dominica
Dominican Republic
Ecuador
Egypt
El Salvador
Equatorial Guinea
Eritrea
Estonia
Ethiopia
Falkland Islands (Malvinas)
Faroe Islands
Fiji
Finland
French Guiana
French Polynesia
French Southern Territories
Gabon
Gambia
Georgia
Ghana
Gibraltar
Greece
Greenland
Grenada
Guadeloupe
Guam
Guatemala
Guernsey
Guinea
Guinea-Bissau
Guyana
Haiti
Heard Island and Mcdonald Islands
Holy See (Vatican City State)
Honduras
Hong Kong
Hungary
Iceland
India
Indonesia
Iran, Islamic Republic Of
Iraq
Ireland
Isle of Man
Israel
Italy
Jamaica
Japan
Jersey
Jordan
Kazakhstan
Kenya
Kiribati
Korea, Democratic People's Republic of
Korea, Republic of
Kuwait
Kyrgyzstan
Lao People's Democratic Republic
Latvia
Lebanon
Lesotho
Liberia
Libyan Arab Jamahiriya
Liechtenstein
Lithuania
Luxembourg
Macao
Madagascar
Malawi
Malaysia
Maldives
Mali
Malta
Marshall Islands
Martinique
Mauritania
Mauritius
Mayotte
Mexico
Micronesia, Federated States of
Moldova, Republic of
Monaco
Mongolia
Montserrat
Morocco
Mozambique
Myanmar
Namibia
Nauru
Nepal
Netherlands
Netherlands Antilles
New Caledonia
New Zealand
Nicaragua
Niger
Nigeria
Niue
Norfolk Island
North Macedonia, Republic of
Northern Mariana Islands
Norway
Oman
Pakistan
Palau
Palestinian Territory, Occupied
Panama
Papua New Guinea
Paraguay
Peru
Philippines
Pitcairn
Poland
Portugal
Puerto Rico
Qatar
Reunion
Romania
Russian Federation
Rwanda
Saint Helena
Saint Kitts and Nevis
Saint Lucia
Saint Pierre and Miquelon
Saint Vincent and the Grenadines
Samoa
San Marino
Sao Tome and Principe
Saudi Arabia
Senegal
Serbia and Montenegro
Seychelles
Sierra Leone
Singapore
Slovakia
Slovenia
Solomon Islands
Somalia
South Africa
South Georgia and the South Sandwich Islands
Spain
Sri Lanka
Sudan
Suriname
Svalbard and Jan Mayen
Swaziland
Sweden
Switzerland
Syrian Arab Republic
Taiwan, Province of China
Tajikistan
Tanzania, United Republic of
Thailand
Timor-Leste
Togo
Tokelau
Tonga
Trinidad and Tobago
Tunisia
Turkey
Turkmenistan
Turks and Caicos Islands
Tuvalu
Uganda
Ukraine
United Arab Emirates
United States Minor Outlying Islands
Uruguay
Uzbekistan
Vanuatu
Venezuela
Viet Nam
Virgin Islands, British
Virgin Islands, U.S.
Wallis and Futuna
Western Sahara
Yemen
Zambia
Zimbabwe
Choose a topicx
General Information
Sales
Customer Service and Technical Support
Partnership and Alliance Inquiries
General information:
info@datasunrise.com
Customer Service and Technical Support:
support.datasunrise.com
Partnership and Alliance Inquiries:
partner@datasunrise.com