mirror of
https://github.com/codeigniter4/CodeIgniter4.git
synced 2025-02-20 11:44:28 +08:00
Merge pull request #609 from davidgv88/foreignkey_forge
Add support for foreign keys to the Forge
This commit is contained in:
commit
d305d5e658
@ -15,6 +15,140 @@ class Checks extends Controller
|
||||
{
|
||||
session()->start();
|
||||
}
|
||||
|
||||
public function forge()
|
||||
{
|
||||
echo '<h1>MySQL</h1>';
|
||||
|
||||
log_message('debug', 'MYSQL TEST');
|
||||
|
||||
$forge_mysql = \Config\Database::forge();
|
||||
|
||||
$forge_mysql->getConnection()->query('SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0;');
|
||||
|
||||
$forge_mysql->dropTable('users', true);
|
||||
|
||||
$forge_mysql->getConnection()->query('SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS;');
|
||||
|
||||
$forge_mysql->addField([
|
||||
'id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11
|
||||
],
|
||||
'name' => [
|
||||
'type' => 'VARCHAR',
|
||||
'constraint' => 50,
|
||||
]
|
||||
]);
|
||||
$forge_mysql->addKey('id', true);
|
||||
$attributes = array('ENGINE' => 'InnoDB');
|
||||
$forge_mysql->createTable('users', true, $attributes);
|
||||
|
||||
$data_insert = array(
|
||||
'id' => 1,
|
||||
'name' => 'User 1',
|
||||
);
|
||||
$forge_mysql->getConnection()->table('users')->insert($data_insert);
|
||||
|
||||
$drop = $forge_mysql->dropTable('invoices', true);
|
||||
|
||||
$forge_mysql->addField([
|
||||
'id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
],
|
||||
'users_id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11
|
||||
],
|
||||
'other_id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11
|
||||
]
|
||||
]);
|
||||
$forge_mysql->addKey('id', true);
|
||||
|
||||
$forge_mysql->addForeignKey('users_id','users','id','CASCADE','CASCADE');
|
||||
$forge_mysql->addForeignKey('other_id','users','id','CASCADE','CASCADE');
|
||||
|
||||
$attributes = array('ENGINE' => 'InnoDB');
|
||||
$res = $forge_mysql->createTable('invoices', true,$attributes);
|
||||
|
||||
if(!$res){
|
||||
var_dump($forge_mysql->getConnection()->mysqli);
|
||||
}else{
|
||||
echo '<br><br>OK';
|
||||
|
||||
var_dump($forge_mysql->getConnection()->getForeignKeyData('invoices'));
|
||||
}
|
||||
|
||||
$res = $forge_mysql->dropForeignKey('invoices','invoices_other_id_foreign');
|
||||
|
||||
|
||||
echo '<h1>PostgreSQL</h1>';
|
||||
|
||||
$forge_pgsql = \Config\Database::forge('pgsql');
|
||||
|
||||
$forge_pgsql->dropTable('users',true, true);
|
||||
|
||||
$forge_pgsql->addField([
|
||||
'id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
'auto_increment' => true,
|
||||
],
|
||||
'name' => [
|
||||
'type' => 'VARCHAR',
|
||||
'constraint' => 50,
|
||||
]
|
||||
]);
|
||||
$forge_pgsql->addKey('id', true);
|
||||
$forge_pgsql->createTable('users', true);
|
||||
|
||||
|
||||
$data_insert = array(
|
||||
'id' => 1,
|
||||
'name' => 'User 1',
|
||||
);
|
||||
$forge_pgsql->getConnection()->table('users')->insert($data_insert);
|
||||
|
||||
$forge_pgsql->dropTable('invoices',true);
|
||||
$forge_pgsql->addField([
|
||||
'id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
'auto_increment' => true,
|
||||
],
|
||||
'users_id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11
|
||||
],
|
||||
'other_id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11
|
||||
],
|
||||
'another_id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11
|
||||
]
|
||||
]);
|
||||
$forge_pgsql->addKey('id', true);
|
||||
|
||||
$forge_pgsql->addForeignKey('users_id','users','id','CASCADE','CASCADE');
|
||||
$forge_pgsql->addForeignKey('other_id','users','id');
|
||||
|
||||
$res = $forge_pgsql->createTable('invoices', true);
|
||||
|
||||
if(!$res){
|
||||
var_dump($forge_pgsql->getConnection()->mysqli);
|
||||
}else{
|
||||
echo '<br><br>OK';
|
||||
var_dump($forge_pgsql->getConnection()->getForeignKeyData('invoices'));
|
||||
}
|
||||
|
||||
//$res = $forge_pgsql->dropForeignKey('invoices','invoices_other_id_foreign');
|
||||
|
||||
}
|
||||
|
||||
|
||||
public function escape()
|
||||
|
@ -1598,7 +1598,7 @@ abstract class BaseConnection implements ConnectionInterface
|
||||
*/
|
||||
public function getFieldData(string $table)
|
||||
{
|
||||
$fields = $this->_fieldData($this->protectIdentifiers($table, true, null, false));
|
||||
$fields = $this->_fieldData($this->protectIdentifiers($table, true, false, false));
|
||||
|
||||
return $fields ?? false;
|
||||
}
|
||||
@ -1618,6 +1618,21 @@ abstract class BaseConnection implements ConnectionInterface
|
||||
return $fields ?? false;
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
* Returns an object with foreign key data
|
||||
*
|
||||
* @param string $table the table name
|
||||
* @return array
|
||||
*/
|
||||
public function getForeignKeyData(string $table)
|
||||
{
|
||||
$fields = $this->_foreignKeyData($this->protectIdentifiers($table, true, false, false));
|
||||
|
||||
return $fields ?? false;
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
|
@ -69,6 +69,13 @@ class Forge
|
||||
* @var array
|
||||
*/
|
||||
protected $primaryKeys = [];
|
||||
|
||||
/**
|
||||
* List of foreign keys.
|
||||
*
|
||||
* @var type
|
||||
*/
|
||||
protected $foreignKeys = [];
|
||||
|
||||
/**
|
||||
* Character set used.
|
||||
@ -330,7 +337,63 @@ class Forge
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
* Add Foreign Key
|
||||
*
|
||||
* @param array $field
|
||||
*
|
||||
* @return \CodeIgniter\Database\Forge
|
||||
*/
|
||||
public function addForeignKey($fieldName= '',$tableName = '', $tableField = '', $onUpdate = false, $onDelete = false)
|
||||
{
|
||||
|
||||
if( ! isset($this->fields[$fieldName]))
|
||||
{
|
||||
throw new \RuntimeException('Field "'.$fieldName.'" not exist');
|
||||
}
|
||||
|
||||
$this->foreignKeys[$fieldName] = [
|
||||
'table' => $tableName,
|
||||
'field' => $tableField,
|
||||
'onDelete' => $onDelete,
|
||||
'onUpdate' => $onUpdate
|
||||
];
|
||||
|
||||
|
||||
return $this;
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
* Foreign Key Drop
|
||||
*
|
||||
* @param string $table Table name
|
||||
* @param string $foreign_name Foreign name
|
||||
*
|
||||
* @return bool
|
||||
*/
|
||||
public function dropForeignKey($table, $foreign_name)
|
||||
{
|
||||
|
||||
$sql = sprintf($this->dropConstraintStr,$this->db->escapeIdentifiers($this->db->DBPrefix.$table),$this->db->escapeIdentifiers($this->db->DBPrefix.$foreign_name));
|
||||
|
||||
if ($sql === false)
|
||||
{
|
||||
if ($this->db->DBDebug)
|
||||
{
|
||||
throw new DatabaseException('This feature is not available for the database you are using.');
|
||||
}
|
||||
|
||||
return false;
|
||||
}
|
||||
|
||||
return $this->db->query($sql);
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
* Create Table
|
||||
*
|
||||
@ -425,8 +488,10 @@ class Forge
|
||||
$columns[$i] = ($columns[$i]['_literal'] !== false) ? "\n\t" . $columns[$i]['_literal'] : "\n\t" . $this->_processColumn($columns[$i]);
|
||||
}
|
||||
|
||||
$columns = implode(',', $columns)
|
||||
. $this->_processPrimaryKeys($table);
|
||||
$columns = implode(',', $columns);
|
||||
|
||||
$columns .= $this->_processPrimaryKeys($table);
|
||||
$columns .= $this->_processForeignKeys($table);
|
||||
|
||||
// Are indexes created from within the CREATE TABLE statement? (e.g. in MySQL)
|
||||
if ($this->createTableKeys === true)
|
||||
@ -472,11 +537,12 @@ class Forge
|
||||
*
|
||||
* @param string $table_name Table name
|
||||
* @param bool $if_exists Whether to add an IF EXISTS condition
|
||||
* @param bool $cascade Whether to add an CASCADE condition
|
||||
*
|
||||
* @return mixed
|
||||
* @throws \CodeIgniter\Database\Exceptions\DatabaseException
|
||||
*/
|
||||
public function dropTable($table_name, $if_exists = false)
|
||||
public function dropTable($table_name, $if_exists = false, $cascade = false)
|
||||
{
|
||||
if ($table_name === '')
|
||||
{
|
||||
@ -488,13 +554,14 @@ class Forge
|
||||
return false;
|
||||
}
|
||||
|
||||
|
||||
// If the prefix is already starting the table name, remove it...
|
||||
if (! empty($this->db->DBPrefix) && strpos($table_name, $this->db->DBPrefix) === 0)
|
||||
{
|
||||
$table_name = substr($table_name, strlen($this->db->DBPrefix));
|
||||
}
|
||||
|
||||
if (($query = $this->_dropTable($this->db->DBPrefix . $table_name, $if_exists)) === true)
|
||||
if (($query = $this->_dropTable($this->db->DBPrefix . $table_name, $if_exists, $cascade)) === true)
|
||||
{
|
||||
return true;
|
||||
}
|
||||
@ -523,10 +590,11 @@ class Forge
|
||||
*
|
||||
* @param string $table Table name
|
||||
* @param bool $if_exists Whether to add an IF EXISTS condition
|
||||
* @param bool $cascade Whether to add an CASCADE condition
|
||||
*
|
||||
* @return string
|
||||
*/
|
||||
protected function _dropTable($table, $if_exists)
|
||||
protected function _dropTable($table, $if_exists, $cascade)
|
||||
{
|
||||
$sql = 'DROP TABLE';
|
||||
|
||||
@ -545,7 +613,9 @@ class Forge
|
||||
}
|
||||
}
|
||||
|
||||
return $sql . ' ' . $this->db->escapeIdentifiers($table);
|
||||
$sql = $sql . ' ' . $this->db->escapeIdentifiers($table);
|
||||
|
||||
return $sql;
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
@ -1076,6 +1146,38 @@ class Forge
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
/**
|
||||
* Process foreign keys
|
||||
*
|
||||
* @param string $table Table name
|
||||
*
|
||||
* @return string
|
||||
*/
|
||||
protected function _processForeignKeys($table) {
|
||||
$sql = '';
|
||||
|
||||
$allowActions = array('CASCADE','SET NULL','NO ACTION','RESTRICT','SET DEFAULT');
|
||||
|
||||
if (count($this->foreignKeys) > 0){
|
||||
foreach ($this->foreignKeys as $field => $fkey) {
|
||||
$name_index = $table.'_'.$field.'_foreign';
|
||||
|
||||
$sql .= ",\n\tCONSTRAINT " . $this->db->escapeIdentifiers($name_index)
|
||||
. ' FOREIGN KEY(' . $this->db->escapeIdentifiers($field) . ') REFERENCES '.$this->db->escapeIdentifiers($this->db->DBPrefix.$fkey['table']).' ('.$this->db->escapeIdentifiers($fkey['field']).')';
|
||||
|
||||
if($fkey['onDelete'] !== false && in_array($fkey['onDelete'], $allowActions)){
|
||||
$sql .= " ON DELETE ".$fkey['onDelete'];
|
||||
}
|
||||
|
||||
if($fkey['onUpdate'] !== false && in_array($fkey['onUpdate'], $allowActions)){
|
||||
$sql .= " ON UPDATE ".$fkey['onDelete'];
|
||||
}
|
||||
|
||||
}
|
||||
}
|
||||
|
||||
return $sql;
|
||||
}
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
|
@ -478,6 +478,49 @@ class Connection extends BaseConnection implements ConnectionInterface
|
||||
return $retval;
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
* Returns an object with Foreign key data
|
||||
*
|
||||
* @param string $table
|
||||
* @return array
|
||||
*/
|
||||
public function _foreignKeyData(string $table)
|
||||
{
|
||||
$sql = '
|
||||
SELECT
|
||||
tc.CONSTRAINT_NAME,
|
||||
tc.TABLE_NAME,
|
||||
rc.REFERENCED_TABLE_NAME
|
||||
FROM information_schema.TABLE_CONSTRAINTS AS tc
|
||||
INNER JOIN information_schema.REFERENTIAL_CONSTRAINTS AS rc
|
||||
ON tc.CONSTRAINT_NAME = rc.CONSTRAINT_NAME
|
||||
WHERE
|
||||
tc.CONSTRAINT_TYPE = '.$this->escape('FOREIGN KEY').' AND
|
||||
tc.TABLE_SCHEMA = '.$this->escape($this->database).' AND
|
||||
tc.TABLE_NAME = '.$this->escape($table);
|
||||
|
||||
if (($query = $this->query($sql)) === false)
|
||||
{
|
||||
return false;
|
||||
}
|
||||
$query = $query->getResultObject();
|
||||
|
||||
$retval = [];
|
||||
foreach ($query as $row)
|
||||
{
|
||||
$obj = new \stdClass();
|
||||
$obj->constraint_name = $row->CONSTRAINT_NAME;
|
||||
$obj->table_name = $row->TABLE_NAME;
|
||||
$obj->foreign_table_name = $row->REFERENCED_TABLE_NAME;
|
||||
|
||||
$retval[] = $obj;
|
||||
}
|
||||
|
||||
return $retval;
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
|
@ -49,6 +49,13 @@ class Forge extends \CodeIgniter\Database\Forge
|
||||
*/
|
||||
protected $createDatabaseStr = 'CREATE DATABASE %s CHARACTER SET %s COLLATE %s';
|
||||
|
||||
/**
|
||||
* DROP CONSTRAINT statement
|
||||
*
|
||||
* @var string
|
||||
*/
|
||||
protected $dropConstraintStr = 'ALTER TABLE %s DROP FOREIGN KEY %s';
|
||||
|
||||
/**
|
||||
* CREATE TABLE keys flag
|
||||
*
|
||||
|
@ -284,7 +284,7 @@ class Connection extends BaseConnection implements ConnectionInterface
|
||||
return 'SELECT "column_name"
|
||||
FROM "information_schema"."columns"
|
||||
WHERE LOWER("table_name") = '
|
||||
. $this->escape(strtolower($table));
|
||||
. $this->escape($this->DBPrefix.strtolower($table));
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
@ -341,7 +341,7 @@ class Connection extends BaseConnection implements ConnectionInterface
|
||||
return false;
|
||||
}
|
||||
$query = $query->getResultObject();
|
||||
|
||||
|
||||
$retval = [];
|
||||
foreach ($query as $row)
|
||||
{
|
||||
@ -352,6 +352,47 @@ class Connection extends BaseConnection implements ConnectionInterface
|
||||
return trim($v);
|
||||
}, $_fields);
|
||||
|
||||
$retval[] = $obj;
|
||||
}
|
||||
|
||||
return $retval;
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
* Returns an object with Foreign key data
|
||||
*
|
||||
* @param string $table
|
||||
* @return array
|
||||
*/
|
||||
public function _foreignKeyData(string $table)
|
||||
{
|
||||
$sql = 'SELECT
|
||||
tc.constraint_name, tc.table_name, kcu.column_name,
|
||||
ccu.table_name AS foreign_table_name,
|
||||
ccu.column_name AS foreign_column_name
|
||||
FROM information_schema.table_constraints AS tc
|
||||
JOIN information_schema.key_column_usage AS kcu
|
||||
ON tc.constraint_name = kcu.constraint_name
|
||||
JOIN information_schema.constraint_column_usage AS ccu
|
||||
ON ccu.constraint_name = tc.constraint_name
|
||||
WHERE constraint_type = '.$this->escape('FOREIGN KEY').' AND tc.table_name = '.$this->escape($table);
|
||||
|
||||
if (($query = $this->query($sql)) === false)
|
||||
{
|
||||
return false;
|
||||
}
|
||||
$query = $query->getResultObject();
|
||||
|
||||
$retval = [];
|
||||
foreach ($query as $row)
|
||||
{
|
||||
$obj = new \stdClass();
|
||||
$obj->constraint_name = $row->constraint_name;
|
||||
$obj->table_name = $row->table_name;
|
||||
$obj->foreign_table_name = $row->foreign_table_name;
|
||||
|
||||
$retval[] = $obj;
|
||||
}
|
||||
|
||||
@ -359,7 +400,7 @@ class Connection extends BaseConnection implements ConnectionInterface
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
|
||||
/**
|
||||
* Returns the last error code and message.
|
||||
*
|
||||
|
@ -42,6 +42,14 @@
|
||||
class Forge extends \CodeIgniter\Database\Forge
|
||||
{
|
||||
|
||||
/**
|
||||
* DROP CONSTRAINT statement
|
||||
*
|
||||
* @var string
|
||||
*/
|
||||
protected $dropConstraintStr = 'ALTER TABLE %s DROP CONSTRAINT %s';
|
||||
|
||||
|
||||
/**
|
||||
* UNSIGNED support
|
||||
*
|
||||
@ -202,4 +210,29 @@ class Forge extends \CodeIgniter\Database\Forge
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
* Drop Table
|
||||
*
|
||||
* Generates a platform-specific DROP TABLE string
|
||||
*
|
||||
* @param string $table Table name
|
||||
* @param bool $if_exists Whether to add an IF EXISTS condition
|
||||
*
|
||||
* @return string
|
||||
*/
|
||||
protected function _dropTable($table, $if_exists, $cascade)
|
||||
{
|
||||
$sql = parent::_dropTable($table, $if_exists, $cascade);
|
||||
|
||||
if($cascade === true)
|
||||
{
|
||||
$sql .= ' CASCADE';
|
||||
}
|
||||
|
||||
return $sql;
|
||||
}
|
||||
|
||||
//--------------------------------------------------------------------
|
||||
|
||||
}
|
||||
|
@ -14,6 +14,104 @@ class ForgeTest extends \CIDatabaseTestCase
|
||||
parent::setUp();
|
||||
$this->forge = \Config\Database::forge($this->DBGroup);
|
||||
}
|
||||
|
||||
public function testCreateTable()
|
||||
{
|
||||
$this->forge->addField([
|
||||
'name' => [
|
||||
'type' => 'VARCHAR',
|
||||
'constraint' => 255,
|
||||
]
|
||||
]);
|
||||
|
||||
$this->forge->createTable('forge_test_table', true);
|
||||
|
||||
$exist = $this->db->tableExists('forge_test_table');
|
||||
|
||||
$this->assertTrue($exist);
|
||||
|
||||
$this->forge->dropTable('forge_test_table', true);
|
||||
|
||||
}
|
||||
|
||||
public function testAddFields()
|
||||
{
|
||||
|
||||
$this->forge->dropTable('forge_test_fields', true);
|
||||
|
||||
$this->forge->addField([
|
||||
'id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
'unsigned' => false,
|
||||
'auto_increment' => true
|
||||
],
|
||||
'username' => [
|
||||
'type' => 'VARCHAR',
|
||||
'constraint' => 255,
|
||||
'unique' => false
|
||||
],
|
||||
'name' => [
|
||||
'type' => 'VARCHAR',
|
||||
'constraint' => 255,
|
||||
],
|
||||
'active' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
'default' => 0
|
||||
],
|
||||
]);
|
||||
|
||||
$this->forge->addKey('id', true);
|
||||
$create = $this->forge->createTable('forge_test_fields', true);
|
||||
|
||||
//Check Field names
|
||||
$fieldsNames = $this->db->getFieldNames('forge_test_fields');
|
||||
$this->assertEquals($fieldsNames, ['id', 'username', 'name', 'active']);
|
||||
|
||||
|
||||
$fieldsData = $this->db->getFieldData('forge_test_fields');
|
||||
|
||||
$this->assertEquals($fieldsData[0]->name, 'id');
|
||||
$this->assertEquals($fieldsData[1]->name, 'username');
|
||||
|
||||
$this->assertEquals($fieldsData[3]->default, 0);
|
||||
|
||||
if($this->db->DBDriver === 'MySQLi')
|
||||
{
|
||||
//Check types
|
||||
$this->assertEquals($fieldsData[0]->type, 'int');
|
||||
$this->assertEquals($fieldsData[1]->type, 'varchar');
|
||||
|
||||
$this->assertEquals($fieldsData[0]->max_length, 11);
|
||||
|
||||
$this->assertEquals($fieldsData[0]->default, NULL);
|
||||
$this->assertEquals($fieldsData[1]->default, NULL);
|
||||
|
||||
$this->assertEquals($fieldsData[0]->primary_key, 1);
|
||||
|
||||
$this->assertEquals($fieldsData[1]->max_length, 255);
|
||||
|
||||
} elseif ($this->db->DBDriver === 'Postgre')
|
||||
{
|
||||
//Check types
|
||||
$this->assertEquals($fieldsData[0]->type, 'integer');
|
||||
$this->assertEquals($fieldsData[1]->type, 'character varying');
|
||||
|
||||
$this->assertEquals($fieldsData[0]->max_length, 32);
|
||||
|
||||
//$this->assertEquals($fieldsData[0]->default, NULL);
|
||||
$this->assertEquals($fieldsData[1]->default, NULL);
|
||||
|
||||
$this->assertEquals($fieldsData[1]->max_length, 255);
|
||||
}else
|
||||
{
|
||||
$this->assertTrue(false, "DB Driver not supported");
|
||||
}
|
||||
|
||||
$this->forge->dropTable('forge_test_fields', true);
|
||||
|
||||
}
|
||||
|
||||
public function testCompositeKey()
|
||||
{
|
||||
@ -42,4 +140,110 @@ class ForgeTest extends \CIDatabaseTestCase
|
||||
|
||||
$this->forge->dropTable('forge_test_1', true);
|
||||
}
|
||||
|
||||
public function testForeignKey()
|
||||
{
|
||||
|
||||
$attributes = [];
|
||||
|
||||
if ($this->db->DBDriver == 'MySQLi')
|
||||
{
|
||||
$attributes = array('ENGINE' => 'InnoDB');
|
||||
}
|
||||
|
||||
$this->forge->addField([
|
||||
'id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
],
|
||||
'name' => [
|
||||
'type' => 'VARCHAR',
|
||||
'constraint' => 255,
|
||||
]
|
||||
]);
|
||||
$this->forge->addKey('id', true);
|
||||
$this->forge->createTable('forge_test_users', true, $attributes);
|
||||
|
||||
$this->forge->addField([
|
||||
'id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
],
|
||||
'users_id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
],
|
||||
'name' => [
|
||||
'type' => 'VARCHAR',
|
||||
'constraint' => 255,
|
||||
]
|
||||
]);
|
||||
$this->forge->addKey('id', true);
|
||||
$this->forge->addForeignKey('users_id', 'forge_test_users', 'id', 'CASCADE', 'CASCADE');
|
||||
|
||||
$this->forge->createTable('forge_test_invoices', true, $attributes);
|
||||
|
||||
$foreignKeyData = $this->db->getForeignKeyData('forge_test_invoices');
|
||||
|
||||
$this->assertEquals($foreignKeyData[0]->constraint_name, $this->db->DBPrefix.'forge_test_invoices_users_id_foreign');
|
||||
$this->assertEquals($foreignKeyData[0]->table_name, $this->db->DBPrefix.'forge_test_invoices');
|
||||
$this->assertEquals($foreignKeyData[0]->foreign_table_name, $this->db->DBPrefix.'forge_test_users');
|
||||
|
||||
$this->forge->dropTable('forge_test_invoices', true);
|
||||
$this->forge->dropTable('forge_test_users', true);
|
||||
|
||||
}
|
||||
|
||||
public function testDropForeignKey()
|
||||
{
|
||||
|
||||
$attributes = [];
|
||||
|
||||
if ($this->db->DBDriver == 'MySQLi')
|
||||
{
|
||||
$attributes = array('ENGINE' => 'InnoDB');
|
||||
}
|
||||
|
||||
$this->forge->addField([
|
||||
'id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
],
|
||||
'name' => [
|
||||
'type' => 'VARCHAR',
|
||||
'constraint' => 255,
|
||||
]
|
||||
]);
|
||||
$this->forge->addKey('id', true);
|
||||
$this->forge->createTable('forge_test_users', true, $attributes);
|
||||
|
||||
$this->forge->addField([
|
||||
'id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
],
|
||||
'users_id' => [
|
||||
'type' => 'INTEGER',
|
||||
'constraint' => 11,
|
||||
],
|
||||
'name' => [
|
||||
'type' => 'VARCHAR',
|
||||
'constraint' => 255,
|
||||
]
|
||||
]);
|
||||
$this->forge->addKey('id', true);
|
||||
$this->forge->addForeignKey('users_id', 'forge_test_users', 'id', 'CASCADE', 'CASCADE');
|
||||
|
||||
$this->forge->createTable('forge_test_invoices', true, $attributes);
|
||||
|
||||
$this->forge->dropForeignKey('forge_test_invoices', 'forge_test_invoices_users_id_foreign');
|
||||
|
||||
$foreignKeyData = $this->db->getForeignKeyData('forge_test_invoices');
|
||||
|
||||
$this->assertEmpty($foreignKeyData);
|
||||
|
||||
$this->forge->dropTable('forge_test_invoices', true);
|
||||
$this->forge->dropTable('forge_test_users', true);
|
||||
|
||||
}
|
||||
}
|
@ -180,6 +180,26 @@ below is for MySQL.
|
||||
// gives KEY `blog_name_blog_label` (`blog_name`, `blog_label`)
|
||||
|
||||
|
||||
Adding Foreign Keys
|
||||
===========
|
||||
|
||||
|
||||
::
|
||||
|
||||
|
||||
$forge->addForeignKey('users_id','users','id');
|
||||
// gives CONSTRAINT `TABLENAME_users_foreign` FOREIGN KEY(`users_id`) REFERENCES `users`(`id`)
|
||||
|
||||
|
||||
You can specify the desired action for the "on delete" and "on update" properties of the constraint:
|
||||
|
||||
::
|
||||
|
||||
$forge->addForeignKey('users_id','users','id','CASCADE','CASCADE');
|
||||
// gives CONSTRAINT `TABLENAME_users_foreign` FOREIGN KEY(`users_id`) REFERENCES `users`(`id`) ON DELETE CASCADE ON UPDATE CASCADE
|
||||
|
||||
|
||||
|
||||
Creating a table
|
||||
================
|
||||
|
||||
@ -224,6 +244,16 @@ Execute a DROP TABLE statement and optionally add an IF EXISTS clause.
|
||||
// Produces: DROP TABLE IF EXISTS table_name
|
||||
$forge->dropTable('table_name',TRUE);
|
||||
|
||||
Dropping a Foreign Key
|
||||
================
|
||||
|
||||
Execute a DROP FOREIGN KEY.
|
||||
|
||||
::
|
||||
|
||||
// Produces: ALTER TABLE 'tablename' DROP FOREIGN KEY 'users_foreign'
|
||||
$forge->dropForeignKey('tablename','users_foreign');
|
||||
|
||||
|
||||
Renaming a table
|
||||
================
|
||||
|
Loading…
x
Reference in New Issue
Block a user