oak-apply-ri
NAME
oak-apply-ri: apply referential integrity on two columns with parent-child relationship.SYNOPSIS
Delete rows from world.City where CountryCode does not have a matching Code in world.Country:oak-apply-ri --parent=world.Country.Code --child=world.City.CountryCode --action=deleteSet CountryCode to NULL where no matching Code is found in world.Country:
oak-apply-ri --parent=world.Country.Code --child=world.City.CountryCode --action=setnullSet CountryCode to NULL in chunks of 100, sleep 500 milliseconds between chunks:
oak-apply-ri --parent=world.Country.Code --child=world.City.CountryCode --action=setnull --chunk-size=100 --sleep=500Same as above. Do not perform, just print the statements:
oak-apply-ri --parent=world.Country.Code --child=world.City.CountryCode -a setnull -c 100 --sleep=500 --print-onlyApply a normal safety level, which demands data types are identical:
oak-apply-ri --parent=world.Country.Code --child=world.City.CountryCode --action=setnull --safety-level=normalApply a high safety level, which demands column names and data types are identical:
oak-apply-ri --parent=world.Country.Code --child=world.City.CountryCode --action=setnull --safety-level=highProvide connection parameters. Prompt for password:
oak-apply-ri --user=root --ask-pass --socket=/tmp/mysql.sock --parent=world.Country.Code --child=world.City.CountryCode --action=deleteUse a defaults file for parameters. Do not perform any safety checks:
oak-apply-ri --defaults-file=/home/myuser/.my-oak.cnf --parent=world.Country.Code --child=world.City.CountryCode --safety-level=none
DESCRIPTION
This tool can be used when you are not using Foreign Keys (either not using a storage engine with supports foreign keys, aush as InnoDB, or not using referencial integrity in your schema), but would like to ensure that Foreign Key contraints apply on your database. With this tool you may perform the following:- Delete "orphaned" rows (as in ON DELETE CASCADE)
- Set "orphaned" rows reference to NULL (as in ON DELETE SET NULL)
- Print our whatever need to done without executing
- Evaluate if adding a Foreign Key contraint is possible
- None: does not perform checks
- Normal: validates that both columns are of the same data type
- High: validates that both columns have the same name.
OPTIONS
-a ACTION, --action=ACTIONAction to take on invalid (orphaned) rows. Can be either delete or setnull.
delete issues a DELETE on orphaned rows. setnull issues an UPDATE on those rows, setting orphaned key to NULL.
setnull is the default value. It is impossible to use 'setnull' for a NOT NULL child column.
--ask-passPrompt for password.
--child=CHILD_COLUMNFully qualified child (referencing) column. Must be in the following format: schema_name.table_name.column_name
-c CHUNK_SIZE, --chunk-size=CHUNK_SIZENumber of values to act on in chunks. This does not map directly to number of rows, but rather to number of distinct orphaned values.
Default chunk size is 0, which means all rows are deleted/updated in one operation
--defaults-file=DEFAULTS_FILERead from MySQL configuration file. Overrides --user, --password, --socket, --port.
Configuration needs to be in the following format:
[client]
user=my_user
password=my_pass
socket=/tmp/mysql.sock
port=3306
MySQL host (default: localhost)
-l SAFETY_LEVEL, --safety-level=SAFETY_LEVELLevel of tests to make in order for action to take place. Valid values are:
none: no tests are performed
normal (default): columns are tested to be of identical date type
high: smae as 'normal' + columns are tested to be of identical names
--parent=PARENT_COLUMNFully qualified parent (referenced) column. Must be in the following format: schema_name.table_name.column_name
-p PASSWORD, --password=PASSWORDMySQL password
-P PORT, --port=PORTTCP/IP port (default: 3306)
--print-onlyDo not execute. Only print statement
--sleep=SLEEP_MILLISNumber of milliseconds to sleep between chunks. Default: 0
-S SOCKET, --socket=SOCKETMySQL socket file. Only applies when host is localhost
-u USER, --user=USERMySQL user
-v, --verbosePrint user friendly messages
ENVIRONMENT
Requires MySQL 5.0 or newer, python 2.3 or newer. python-mysqldb must be installed in order to use this tool. You canapt-get install python-mysqldbor
yum install mysql-python
SEE ALSO
LICENSE
This tool is released under the BSD license.Copyright (c) 2008 - 2010, Shlomi Noach All rights reserved. Redistribution and use in source and binary forms, with or without modification, are permitted provided that the following conditions are met: * Redistributions of source code must retain the above copyright notice, this list of conditions and the following disclaimer. * Redistributions in binary form must reproduce the above copyright notice, this list of conditions and the following disclaimer in the documentation and/or other materials provided with the distribution. * Neither the name of the organization nor the names of its contributors may be used to endorse or promote products derived from this software without specific prior written permission. THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.