Skip to content

Commit

Permalink
Browse files Browse the repository at this point in the history
List tables and describe for postgres
  • Loading branch information
lorenzo committed Apr 1, 2013
1 parent ba22518 commit 32f6995
Show file tree
Hide file tree
Showing 3 changed files with 231 additions and 5 deletions.
2 changes: 1 addition & 1 deletion lib/Cake/Model/Datasource/Database/Connection.php
Expand Up @@ -449,7 +449,7 @@ public function listTables() {
* @return array The schema data for the requested table.
*/
public function describe($table) {
list($sql, $params) = $this->_driver->describeTableSql($table);
list($sql, $params) = $this->_driver->describeTableSql($table, $this->_config);
$statement = $this->execute($sql, $params);
$schema = [];

Expand Down
Expand Up @@ -155,7 +155,7 @@ protected function _transformFunctionExpression(FunctionExpression $expression)
* getting tables from.
* @return array An array of (sql, params) to execute.
*/
public function listTablesSql() {
public function listTablesSql($config) {
$sql = "SELECT table_name as name FROM INFORMATION_SCHEMA.tables WHERE table_schema = ? ORDER BY name";
$schema = empty($config['schema']) ? 'public' : $config['schema'];
return [$sql, [$schema]];
Expand All @@ -165,12 +165,25 @@ public function listTablesSql() {
* Get the SQL to describe a table in Sqlite.
*
* @param string $table The table name to describe
* @param array $config The connection configuration to use
* @return array An array of (sql, params) to execute.
*/
public function describeTableSql($table) {
public function describeTableSql($table, $config) {
$sql =
"SELECT DISTINCT table_schema AS schema, column_name AS name, data_type AS type,
is_nullable AS null, column_default AS default, ordinal_position AS position,
character_maximum_length AS char_length, character_octet_length AS oct_length,
d.description as comment, i.indisprimary = 't' as pk
FROM information_schema.columns c
INNER JOIN pg_catalog.pg_namespace ns ON (ns.nspname = table_schema)
INNER JOIN pg_catalog.pg_class cl ON (cl.relnamespace = ns.oid AND cl.relname = table_name)
LEFT JOIN pg_catalog.pg_index i ON (i.indrelid = cl.oid AND i.indkey[0] = c.ordinal_position)
LEFT JOIN pg_catalog.pg_description d on (cl.oid = d.objoid AND d.objsubid = c.ordinal_position)
WHERE table_name = ? AND table_schema = ? ORDER BY position";
$schema = empty($config['schema']) ? 'public' : $config['schema'];
return [$sql, [$table, $schema]];
}


/**
* Convert a column definition to the abstract types.
*
Expand All @@ -181,14 +194,51 @@ public function describeTableSql($table) {
* @return array List of (type, length)
*/
public function convertColumn($column) {
$col = strtolower($column);
if (in_array($col, array('date', 'time', 'boolean'))) {
return [$col, null];
}
if (strpos($col, 'timestamp') !== false) {
return ['datetime', null];
}
if ($col === 'serial' || $col === 'integer') {
return ['integer', 10];
}
if ($col === 'bigserial' || $col === 'bigint') {
return ['biginteger', 20];
}
if ($col === 'smallint') {
return ['integer', 5];
}
if (strpos($col, 'char') !== false) {
return ['string', null];
}
if (strpos($col, 'text') !== false) {
return ['text', null];
}
if ($col === 'bytea') {
return ['binary', null];
}
if ($col === 'real' || strpos($col, 'double') !== false) {
return ['float', null];
}
if (strpos($col, 'numeric') !== false) {
return ['decimal', null];
}
return ['text', null];
}

/**
* Additional metadata columns in table descriptions.
* Get additional column meta data used in schema reflections.
*
* @return array
*/
public function extraSchemaColumns() {
return [
'comment' => [
'column' => 'comment',
]
];
}

/**
Expand All @@ -197,6 +247,29 @@ public function extraSchemaColumns() {
* @return array An array of with the key/values of schema data.
*/
public function convertFieldDescription($row, $fieldParams = []) {
list($type, $length) = $this->convertColumn($row['type']);

if ($type === 'boolean') {
$row['default'] = $row['default'] === 'false' ? 0 : $row['default'];
$row['default'] = $row['default'] === 'true' ? 1 : $row['default'];
}

$schema = [];
$schema[$row['name']] = [
'type' => $type,
'null' => $row['null'] === 'YES' ? true : false,
'default' => $row['default'],
'length' => $row['char_length'] ?: $length,
];
if (!empty($row['pk'])) {
$schema[$row['name']]['key'] = 'primary';
}
foreach ($fieldParams as $key => $metadata) {
if (!empty($row[$metadata['column']])) {
$schema[$row['name']][$key] = $row[$metadata['column']];
}
}
return $schema;
}

}
Expand Up @@ -174,6 +174,100 @@ protected function _createTables($connection) {
$connection->execute('COMMENT ON COLUMN "articles"."title" IS \'a title\'');
}

/**
* Dataprovider for column testing
*
* @return array
*/
public static function columnProvider() {
return [
[
'TIMESTAMP',
['datetime', null]
],
[
'TIMESTAMP WITHOUT TIME ZONE',
['datetime', null]
],
[
'DATE',
['date', null]
],
[
'TIME',
['time', null]
],
[
'SMALLINT',
['integer', 5]
],
[
'INTEGER',
['integer', 10]
],
[
'SERIAL',
['integer', 10]
],
[
'BIGINT',
['biginteger', 20]
],
[
'NUMERIC',
['decimal', null]
],
[
'VARCHAR',
['string', null]
],
[
'CHARACTER VARYING',
['string', null]
],
[
'CHAR',
['string', null]
],
[
'CHARACTER',
['string', null]
],
[
'TEXT',
['text', null]
],
[
'BYTEA',
['binary', null]
],
[
'REAL',
['float', null]
],
[
'DOUBLE PRECISION',
['float', null]
],
[
'BIGSERIAL',
['biginteger', 20]
],
];
}

/**
* Test parsing Postgres column types.
*
* @dataProvider columnProvider
* @return void
*/
public function testConvertColumnType($input, $expected) {
$driver = new Postgres();
$this->assertEquals($expected, $driver->convertColumn($input));
}


/**
* Test listing tables with Postgres
*
Expand All @@ -190,4 +284,63 @@ public function testListTables() {
$this->assertEquals('authors', $result[1]);
}

/**
* Test describing a table with Postgres
*
* @return void
*/
public function testDescribeTable() {
$connection = new Connection(Configure::read('Datasource.test'));
$this->_createTables($connection);

$result = $connection->describe('articles');
$expected = [
'id' => [
'type' => 'biginteger',
'null' => false,
'default' => null,
'length' => 20,
'key' => 'primary',
],
'title' => [
'type' => 'string',
'null' => true,
'default' => null,
'length' => 20,
'comment' => 'a title',
],
'body' => [
'type' => 'text',
'null' => true,
'default' => null,
'length' => null,
],
'author_id' => [
'type' => 'integer',
'null' => false,
'default' => null,
'length' => 10,
],
'published' => [
'type' => 'boolean',
'null' => true,
'default' => 0,
'length' => null,
],
'views' => [
'type' => 'integer',
'null' => true,
'default' => 0,
'length' => 5,
],
'created' => [
'type' => 'datetime',
'null' => true,
'default' => null,
'length' => null,
],
];
$this->assertEquals($expected, $result);
}

}

0 comments on commit 32f6995

Please sign in to comment.