Update foreign key driver methods to return the same kind of information

This commit is contained in:
Timothy Warren 2014-04-15 16:15:08 -04:00
parent 64a6878a47
commit 80595dfbbe
11 changed files with 123 additions and 26 deletions

View File

@ -126,7 +126,7 @@ interface SQL_Interface {
* Get the list of foreign keys for the current * Get the list of foreign keys for the current
* table * table
* *
* @parma string $table * @param string $table
* @return array * @return array
*/ */
public function fk_list($table); public function fk_list($table);

View File

@ -276,20 +276,16 @@ SQL;
* Get the list of foreign keys for the current * Get the list of foreign keys for the current
* table * table
* *
* @parma string $table * @param string $table
* @return string * @return string
*/ */
public function fk_list($table) public function fk_list($table)
{ {
return <<<SQL return <<<SQL
SELECT DISTINCT SELECT DISTINCT
rc.RDB\$CONSTRAINT_NAME AS "constraint_name", TRIM(d1.RDB\$FIELD_NAME) AS "child_column",
rc.RDB\$RELATION_NAME AS "on table", TRIM(d2.RDB\$DEPENDED_ON_NAME) AS "parent_table",
d1.RDB\$FIELD_NAME AS "on field", TRIM(d2.RDB\$FIELD_NAME) AS "parent_column"
d2.RDB\$DEPENDED_ON_NAME AS "references table",
d2.RDB\$FIELD_NAME AS "references field",
refc.RDB\$UPDATE_RULE AS "on update",
refc.RDB\$DELETE_RULE AS "on delete"
FROM RDB\$RELATION_CONSTRAINTS AS rc FROM RDB\$RELATION_CONSTRAINTS AS rc
LEFT JOIN RDB\$REF_CONSTRAINTS refc ON rc.RDB\$CONSTRAINT_NAME = refc.RDB\$CONSTRAINT_NAME LEFT JOIN RDB\$REF_CONSTRAINTS refc ON rc.RDB\$CONSTRAINT_NAME = refc.RDB\$CONSTRAINT_NAME
LEFT JOIN RDB\$DEPENDENCIES d1 ON d1.RDB\$DEPENDED_ON_NAME = rc.RDB\$RELATION_NAME LEFT JOIN RDB\$DEPENDENCIES d1 ON d1.RDB\$DEPENDED_ON_NAME = rc.RDB\$RELATION_NAME

View File

@ -197,16 +197,22 @@ class MySQL_SQL extends Abstract_SQL {
* Get the list of foreign keys for the current * Get the list of foreign keys for the current
* table * table
* *
* @parma string $table * @param string $table
* @return string * @return string
*/ */
public function fk_list($table) public function fk_list($table)
{ {
return <<<SQL return <<<SQL
SELECT `TABLE_NAME`,`COLUMN_NAME`,`CONSTRAINT_NAME`, SELECT DISTINCT `kcu`.`COLUMN_NAME` as `child_column`,
`REFERENCED_TABLE_NAME`,`REFERENCED_COLUMN_NAME` `kcu`.`REFERENCED_TABLE_NAME` as `parent_table`,
FROM `INFORMATION_SCHEMA`.`KEY_COLUMN_USAGE` `kcu`.`REFERENCED_COLUMN_NAME` as `parent_column`
WHERE `REFERENCED_TABLE_NAME` = '{$table}'; FROM `INFORMATION_SCHEMA`.`TABLE_CONSTRAINTS` `tc`
INNER JOIN `INFORMATION_SCHEMA`.`KEY_COLUMN_USAGE` `kcu`
ON `kcu`.`CONSTRAINT_NAME`=`tc`.`CONSTRAINT_NAME`
WHERE `tc`.`CONSTRAINT_TYPE`='FOREIGN KEY'
AND `tc`.`TABLE_NAME`='{$table}'
-- AND `parent_table` IS NOT NULL
-- AND `parent_column` IS NOT NULL
SQL; SQL;
} }

View File

@ -226,7 +226,7 @@ SQL;
* Get the list of foreign keys for the current * Get the list of foreign keys for the current
* table * table
* *
* @parma string $table * @param string $table
* @return string * @return string
*/ */
public function fk_list($table) public function fk_list($table)
@ -245,8 +245,8 @@ SQL;
FROM "pg_class" "cl" FROM "pg_class" "cl"
JOIN "pg_namespace" "ns" ON "cl"."relnamespace" = "ns"."oid" JOIN "pg_namespace" "ns" ON "cl"."relnamespace" = "ns"."oid"
JOIN "pg_constraint" "con1" ON "con1"."conrelid" = "cl"."oid" JOIN "pg_constraint" "con1" ON "con1"."conrelid" = "cl"."oid"
WHERE "cl"."relname" = 'child_table' WHERE "cl"."relname" = '{$table}'
AND "ns"."nspname" = 'child_schema' AND "ns"."nspname" = 'public'
AND "con1"."contype" = 'f' AND "con1"."contype" = 'f'
) )
"con" "con"

View File

@ -79,6 +79,31 @@ class SQLite extends Abstract_Driver {
// -------------------------------------------------------------------------- // --------------------------------------------------------------------------
/**
* Retrieve foreign keys for the table
*
* @param string $table
* @return array
*/
public function get_fks($table)
{
$return_rows = array();
$rows = parent::get_fks($table);
foreach($rows as $row)
{
$return_rows[] = array(
'child_column' => $row['from'],
'parent_table' => $row['table'],
'parent_column' => $row['to']
);
}
return $return_rows;
}
// --------------------------------------------------------------------------
/** /**
* Create sql for batch insert * Create sql for batch insert
* *

View File

@ -74,8 +74,14 @@ abstract class DBTest extends Query_TestCase {
public function testGetFKs() public function testGetFKs()
{ {
$keys = $this->db->get_fks('test'); $expected = array(array(
$this->assertTrue(is_array($keys)); 'child_column' => 'ext_id',
'parent_table' => 'testconstraints',
'parent_column' => 'someid'
));
$keys = $this->db->get_fks('testconstraints2');
$this->assertEqual($expected, $keys);
} }
// -------------------------------------------------------------------------- // --------------------------------------------------------------------------

View File

@ -229,7 +229,7 @@ SQL;
// -------------------------------------------------------------------------- // --------------------------------------------------------------------------
public function testGetsProcedures() public function testGetProcedures()
{ {
$this->assertTrue(is_array($this->db->get_procedures())); $this->assertTrue(is_array($this->db->get_procedures()));
} }

View File

@ -116,6 +116,25 @@ CREATE VIEW "numbersview" AS
SELECT * SELECT *
FROM NUMBERS FROM NUMBERS
WHERE NUMBER > 100; WHERE NUMBER > 100;
CREATE TABLE "testconstraints" (
someid integer NOT NULL,
somename TEXT NOT NULL,
CONSTRAINT testconstraints_id_pk PRIMARY KEY (someid)
);
CREATE TABLE "testconstraints2" (
ext_id integer NOT NULL,
modified text,
uniquefield text NOT NULL,
usraction integer NOT NULL,
CONSTRAINT testconstraints_id_fk FOREIGN KEY (ext_id)
REFERENCES testconstraints (someid)
ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT unique_2_fields_idx UNIQUE (modified, usraction),
CONSTRAINT uniquefld_idx UNIQUE (uniquefield)
);
;
;
SQL; SQL;
$expected_array = explode("\n", $expected); $expected_array = explode("\n", $expected);

View File

@ -92,3 +92,22 @@ BEGIN
END ^ END ^
SET TERM ; ^ SET TERM ; ^
-- TABLEs for testing CONSTRAINTs
CREATE TABLE "testconstraints" (
"someid" integer NOT NULL,
"somename" char(10) NOT NULL,
CONSTRAINT "testconstraints_id_pk" PRIMARY KEY ("someid")
);
CREATE TABLE "testconstraints2" (
"ext_id" integer NOT NULL,
"modified" date,
"uniquefield" char(10) NOT NULL,
"usraction" integer NOT NULL,
CONSTRAINT "testconstraints_id_fk" FOREIGN KEY ("ext_id")
REFERENCES "testconstraints" ("someid")
ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT "unique_2_fields_idx" UNIQUE ("modified", "usraction"),
CONSTRAINT "uniquefld_idx" UNIQUE ("uniquefield")
);

View File

@ -27,7 +27,8 @@ ALTER TABLE TEST2 ADD CONSTRAINT TEST2_FIELD4_IDX UNIQUE (FIELD4);
CREATE INDEX TEST2_FIELD5_IDX ON TEST2(FIELD5); CREATE INDEX TEST2_FIELD5_IDX ON TEST2(FIELD5);
-- TABLE NUMBERS -- TABLE NUMBERS
CREATE TABLE IF NOT EXISTS NUMBERS ( DROP TABLE IF EXISTS NUMBERS;
CREATE TABLE NUMBERS (
NUMBER INTEGER DEFAULT '0' NOT NULL, NUMBER INTEGER DEFAULT '0' NOT NULL,
EN CHAR(100) NOT NULL, EN CHAR(100) NOT NULL,
FR CHAR(100) NOT NULL FR CHAR(100) NOT NULL
@ -66,19 +67,22 @@ FROM NUMBERS
WHERE NUMBER > 100; WHERE NUMBER > 100;
-- TABLEs for testing CONSTRAINTs -- TABLEs for testing CONSTRAINTs
CREATE TABLE IF NOT EXISTS testconstraints ( DROP TABLE IF EXISTS testconstraints;
CREATE TABLE testconstraints (
someid integer NOT NULL, someid integer NOT NULL,
somename varchar(10) NOT NULL, somename varchar(10) NOT NULL,
CONSTRAINT testconstraints_id_pk PRIMARY KEY (someid) CONSTRAINT testconstraints_id_pk PRIMARY KEY (someid)
); );
CREATE TABLE IF NOT EXISTS testconstraints2 ( DROP TABLE IF EXISTS testconstraints2;
CREATE TABLE testconstraints2 (
ext_id integer NOT NULL, ext_id integer NOT NULL,
modified date, modified date,
uniquefield varchar(10) NOT NULL, uniquefield varchar(10) NOT NULL,
usraction integer NOT NULL, usraction integer NOT NULL,
CONSTRAINT testconstraints_id_fk FOREIGN KEY (ext_id) CONSTRAINT testconstraints_id_fk FOREIGN KEY (ext_id)
REFERENCES testconstraints (someid) MATCH SIMPLE REFERENCES testconstraints (someid)
ON UPDATE CASCADE ON DELETE CASCADE, ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT unique_2_fields_idx UNIQUE (modified, usraction), CONSTRAINT unique_2_fields_idx UNIQUE (modified, usraction),
CONSTRAINT uniquefld_idx UNIQUE (uniquefield) CONSTRAINT uniquefld_idx UNIQUE (uniquefield)
); );

View File

@ -57,4 +57,26 @@ DROP VIEW IF EXISTS "numbersview";
CREATE VIEW "numbersview" AS CREATE VIEW "numbersview" AS
SELECT * SELECT *
FROM NUMBERS FROM NUMBERS
WHERE NUMBER > 100; WHERE NUMBER > 100;
-- TABLEs for testing CONSTRAINTs
DROP TABLE IF EXISTS "testconstraints";
CREATE TABLE "testconstraints" (
someid integer NOT NULL,
somename TEXT NOT NULL,
CONSTRAINT testconstraints_id_pk PRIMARY KEY (someid)
);
DROP TABLE IF EXISTS "testconstraints2";
CREATE TABLE "testconstraints2" (
ext_id integer NOT NULL,
modified text,
uniquefield text NOT NULL,
usraction integer NOT NULL,
CONSTRAINT testconstraints_id_fk FOREIGN KEY (ext_id)
REFERENCES testconstraints (someid)
ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT unique_2_fields_idx UNIQUE (modified, usraction),
CONSTRAINT uniquefld_idx UNIQUE (uniquefield)
);