Skip to content

Commit

Permalink
Merge pull request #6221 from sclubricants/SQLiteConnectiongetIndexData
Browse files Browse the repository at this point in the history
SQLite3 Connection getIndexData()
  • Loading branch information
kenjis authored Jul 13, 2022
2 parents d3b9114 + 97c89e1 commit 9755623
Show file tree
Hide file tree
Showing 7 changed files with 176 additions and 35 deletions.
50 changes: 32 additions & 18 deletions system/Database/SQLite3/Connection.php
Original file line number Diff line number Diff line change
Expand Up @@ -265,34 +265,48 @@ protected function _fieldData(string $table): array
*/
protected function _indexData(string $table): array
{
// Get indexes
// Don't use PRAGMA index_list, so we can preserve index order
$sql = "SELECT name FROM sqlite_master WHERE type='index' AND tbl_name=" . $this->escape(strtolower($table));
$sql = "SELECT 'PRIMARY' as indexname, l.name as fieldname, 'PRIMARY' as indextype
FROM pragma_table_info(" . $this->escape(strtolower($table)) . ") as l
WHERE l.pk <> 0
UNION ALL
SELECT sqlite_master.name as indexname, ii.name as fieldname,
CASE
WHEN ti.pk <> 0 AND sqlite_master.name LIKE 'sqlite_autoindex_%' THEN 'PRIMARY'
WHEN sqlite_master.name LIKE 'sqlite_autoindex_%' THEN 'UNIQUE'
WHEN sqlite_master.sql LIKE '% UNIQUE %' THEN 'UNIQUE'
ELSE 'INDEX'
END as indextype
FROM sqlite_master
INNER JOIN pragma_index_xinfo(sqlite_master.name) ii ON ii.name IS NOT NULL
LEFT JOIN pragma_table_info(" . $this->escape(strtolower($table)) . ") ti ON ti.name = ii.name
WHERE sqlite_master.type='index' AND sqlite_master.tbl_name = " . $this->escape(strtolower($table)) . ' COLLATE NOCASE';

if (($query = $this->query($sql)) === false) {
throw new DatabaseException(lang('Database.failGetIndexData'));
}
$query = $query->getResultObject();

$retVal = [];
$tempVal = [];

foreach ($query as $row) {
$obj = new stdClass();

$obj->name = $row->name;

// Get fields for index
$obj->fields = [];

if (false === $fields = $this->query('PRAGMA index_info(' . $this->escape(strtolower($row->name)) . ')')) {
throw new DatabaseException(lang('Database.failGetIndexData'));
if ($row->indextype === 'PRIMARY') {
$tempVal['PRIMARY']['indextype'] = $row->indextype;
$tempVal['PRIMARY']['indexname'] = $row->indexname;
$tempVal['PRIMARY']['fields'][$row->fieldname] = $row->fieldname;
} else {
$tempVal[$row->indexname]['indextype'] = $row->indextype;
$tempVal[$row->indexname]['indexname'] = $row->indexname;
$tempVal[$row->indexname]['fields'][$row->fieldname] = $row->fieldname;
}
}

$fields = $fields->getResultObject();

foreach ($fields as $field) {
$obj->fields[] = $field->name;
}
$retVal = [];

foreach ($tempVal as $val) {
$obj = new stdClass();
$obj->name = $val['indexname'];
$obj->fields = array_values($val['fields']);
$obj->type = $val['indextype'];
$retVal[$obj->name] = $obj;
}

Expand Down
17 changes: 12 additions & 5 deletions system/Database/SQLite3/Table.php
Original file line number Diff line number Diff line change
Expand Up @@ -110,6 +110,13 @@ public function fromTable(string $table)

$this->keys = array_merge($this->keys, $this->formatKeys($this->db->getIndexData($table)));

// if primary key index exists twice then remove psuedo index name 'primary'.
$primaryIndexes = array_filter($this->keys, static fn ($index) => $index['type'] === 'primary');

if (! empty($primaryIndexes) && count($primaryIndexes) > 1 && array_key_exists('primary', $this->keys)) {
unset($this->keys['primary']);
}

$this->foreignKeys = $this->db->getForeignKeyData($table);

return $this;
Expand Down Expand Up @@ -316,7 +323,7 @@ protected function formatFields($fields)
];

if ($field->primary_key) {
$this->keys[$field->name] = [
$this->keys['primary'] = [
'fields' => [$field->name],
'type' => 'primary',
];
Expand All @@ -343,9 +350,9 @@ protected function formatKeys($keys)
$return = [];

foreach ($keys as $name => $key) {
$return[$name] = [
$return[strtolower($name)] = [
'fields' => $key->fields,
'type' => 'index',
'type' => strtolower($key->type),
];
}

Expand All @@ -362,8 +369,8 @@ protected function dropIndexes()
return;
}

foreach ($this->keys as $name => $key) {
if ($key['type'] === 'primary' || $key['type'] === 'unique') {
foreach (array_keys($this->keys) as $name) {
if ($name === 'primary') {
continue;
}

Expand Down
24 changes: 16 additions & 8 deletions tests/system/Database/Live/ForgeTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -879,14 +879,11 @@ public function testAddFields()

public function testCompositeKey()
{
// SQLite3 uses auto increment different
$uniqueOrAuto = $this->db->DBDriver === 'SQLite3' ? 'unique' : 'auto_increment';

$this->forge->addField([
'id' => [
'type' => 'INTEGER',
'constraint' => 3,
$uniqueOrAuto => true,
'type' => 'INTEGER',
'constraint' => 3,
'auto_increment' => true,
],
'code' => [
'type' => 'VARCHAR',
Expand All @@ -912,29 +909,38 @@ public function testCompositeKey()
$this->assertSame($keys['PRIMARY']->name, 'PRIMARY');
$this->assertSame($keys['PRIMARY']->fields, ['id']);
$this->assertSame($keys['PRIMARY']->type, 'PRIMARY');

$this->assertSame($keys['code_company']->name, 'code_company');
$this->assertSame($keys['code_company']->fields, ['code', 'company']);
$this->assertSame($keys['code_company']->type, 'INDEX');

$this->assertSame($keys['code_active']->name, 'code_active');
$this->assertSame($keys['code_active']->fields, ['code', 'active']);
$this->assertSame($keys['code_active']->type, 'UNIQUE');
} elseif ($this->db->DBDriver === 'Postgre') {
$this->assertSame($keys['pk_db_forge_test_1']->name, 'pk_db_forge_test_1');
$this->assertSame($keys['pk_db_forge_test_1']->fields, ['id']);
$this->assertSame($keys['pk_db_forge_test_1']->type, 'PRIMARY');

$this->assertSame($keys['db_forge_test_1_code_company']->name, 'db_forge_test_1_code_company');
$this->assertSame($keys['db_forge_test_1_code_company']->fields, ['code', 'company']);
$this->assertSame($keys['db_forge_test_1_code_company']->type, 'INDEX');

$this->assertSame($keys['db_forge_test_1_code_active']->name, 'db_forge_test_1_code_active');
$this->assertSame($keys['db_forge_test_1_code_active']->fields, ['code', 'active']);
$this->assertSame($keys['db_forge_test_1_code_active']->type, 'UNIQUE');
} elseif ($this->db->DBDriver === 'SQLite3') {
$this->assertSame($keys['sqlite_autoindex_db_forge_test_1_1']->name, 'sqlite_autoindex_db_forge_test_1_1');
$this->assertSame($keys['sqlite_autoindex_db_forge_test_1_1']->fields, ['id']);
$this->assertSame($keys['PRIMARY']->name, 'PRIMARY');
$this->assertSame($keys['PRIMARY']->fields, ['id']);
$this->assertSame($keys['PRIMARY']->type, 'PRIMARY');

$this->assertSame($keys['db_forge_test_1_code_company']->name, 'db_forge_test_1_code_company');
$this->assertSame($keys['db_forge_test_1_code_company']->fields, ['code', 'company']);
$this->assertSame($keys['db_forge_test_1_code_company']->type, 'INDEX');

$this->assertSame($keys['db_forge_test_1_code_active']->name, 'db_forge_test_1_code_active');
$this->assertSame($keys['db_forge_test_1_code_active']->fields, ['code', 'active']);
$this->assertSame($keys['db_forge_test_1_code_active']->type, 'UNIQUE');
} elseif ($this->db->DBDriver === 'SQLSRV') {
$this->assertSame($keys['pk_db_forge_test_1']->name, 'pk_db_forge_test_1');
$this->assertSame($keys['pk_db_forge_test_1']->fields, ['id']);
Expand All @@ -951,9 +957,11 @@ public function testCompositeKey()
$this->assertSame($keys['pk_db_forge_test_1']->name, 'pk_db_forge_test_1');
$this->assertSame($keys['pk_db_forge_test_1']->fields, ['id']);
$this->assertSame($keys['pk_db_forge_test_1']->type, 'PRIMARY');

$this->assertSame($keys['db_forge_test_1_code_company']->name, 'db_forge_test_1_code_company');
$this->assertSame($keys['db_forge_test_1_code_company']->fields, ['code', 'company']);
$this->assertSame($keys['db_forge_test_1_code_company']->type, 'INDEX');

$this->assertSame($keys['db_forge_test_1_code_active']->name, 'db_forge_test_1_code_active');
$this->assertSame($keys['db_forge_test_1_code_active']->fields, ['code', 'active']);
$this->assertSame($keys['db_forge_test_1_code_active']->type, 'UNIQUE');
Expand Down
8 changes: 4 additions & 4 deletions tests/system/Database/Live/SQLite/AlterTableTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -110,10 +110,10 @@ public function testFromTableFillsDetails()
$this->assertCount(3, $keys);
$this->assertArrayHasKey('foo_name', $keys);
$this->assertSame(['fields' => ['name'], 'type' => 'index'], $keys['foo_name']);
$this->assertArrayHasKey('id', $keys);
$this->assertSame(['fields' => ['id'], 'type' => 'primary'], $keys['id']);
$this->assertArrayHasKey('id', $keys);
$this->assertSame(['fields' => ['id'], 'type' => 'primary'], $keys['id']);
$this->assertArrayHasKey('foo_email', $keys);
$this->assertSame(['fields' => ['email'], 'type' => 'unique'], $keys['foo_email']);
$this->assertArrayHasKey('primary', $keys);
$this->assertSame(['fields' => ['id'], 'type' => 'primary'], $keys['primary']);
}

public function testDropColumnSuccess()
Expand Down
109 changes: 109 additions & 0 deletions tests/system/Database/Live/SQLite/GetIndexDataTest.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,109 @@
<?php

/**
* This file is part of CodeIgniter 4 framework.
*
* (c) CodeIgniter Foundation <[email protected]>
*
* For the full copyright and license information, please view
* the LICENSE file that was distributed with this source code.
*/

namespace CodeIgniter\Database\Live\SQLite;

use CodeIgniter\Database\SQLite3\Connection;
use CodeIgniter\Database\SQLite3\Forge;
use CodeIgniter\Test\CIUnitTestCase;
use CodeIgniter\Test\DatabaseTestTrait;
use Config\Database;
use stdClass;

/**
* @group DatabaseLive
*
* @internal
*/
final class GetIndexDataTest extends CIUnitTestCase
{
use DatabaseTestTrait;

/**
* In setUp() db connection is changed. So migration doesn't work
*
* @var bool
*/
protected $migrate = false;

/**
* @var Connection
*/
protected $db;

private Forge $forge;

protected function setUp(): void
{
parent::setUp();

$config = [
'DBDriver' => 'SQLite3',
'database' => 'database.db',
'DBDebug' => true,
];

$this->db = db_connect($config);
$this->forge = Database::forge($config);
}

public function testGetIndexData()
{
// INTEGER PRIMARY KEY AUTO_INCREMENT doesn't get an index by default
$this->forge->addField([
'id' => ['type' => 'INTEGER', 'constraint' => 3, 'auto_increment' => true],
'userid' => ['type' => 'INTEGER', 'constraint' => 3],
'name' => ['type' => 'VARCHAR', 'constraint' => 80],
'email' => ['type' => 'VARCHAR', 'constraint' => 100],
'country' => ['type' => 'VARCHAR', 'constraint' => 40],
'created_at' => ['type' => 'DATETIME', 'null' => true],
'updated_at' => ['type' => 'DATETIME', 'null' => true],
'deleted_at' => ['type' => 'DATETIME', 'null' => true],
])
->addKey(['id'], true)
->addUniqueKey('email')
->addKey('country')
->createTable('testuser', true);

$expectedIndexes = [];

$row = new stdclass();
$row->name = 'PRIMARY';
$row->fields = ['id'];
$row->type = 'PRIMARY';
$expectedIndexes['PRIMARY'] = $row;

$row = new stdclass();
$row->name = 'testuser_email';
$row->fields = ['email'];
$row->type = 'UNIQUE';
$expectedIndexes['testuser_email'] = $row;

$row = new stdclass();
$row->name = 'testuser_country';
$row->fields = ['country'];
$row->type = 'INDEX';
$expectedIndexes['testuser_country'] = $row;

$indexes = $this->db->getIndexData('testuser');

$this->assertSame($expectedIndexes['PRIMARY']->fields, $indexes['PRIMARY']->fields);
$this->assertSame($expectedIndexes['PRIMARY']->type, $indexes['PRIMARY']->type);

$this->assertSame($expectedIndexes['testuser_email']->fields, $indexes['testuser_email']->fields);
$this->assertSame($expectedIndexes['testuser_email']->type, $indexes['testuser_email']->type);

$this->assertSame($expectedIndexes['testuser_country']->fields, $indexes['testuser_country']->fields);
$this->assertSame($expectedIndexes['testuser_country']->type, $indexes['testuser_country']->type);

$this->forge->dropTable('testuser', true);
}
}
1 change: 1 addition & 0 deletions user_guide_src/source/changelogs/v4.3.0.rst
Original file line number Diff line number Diff line change
Expand Up @@ -38,6 +38,7 @@ Enhancements
- Added ``$routes->useSupportedLocalesOnly(true)`` so that the Router returns 404 Not Found if the locale in the URL is not supported in ``Config\App::$supportedLocales``. See :ref:`Localization <localization-in-routes>`
- Added methods ``replace()``, ``addLineAfter()`` and ``addLineBefore()`` to modify files in Publisher. See :ref:`Publisher <publisher-modifying-files>` for details.
- The call handler for Spark commands from the ``CodeIgniter\CodeIgniter`` class has been extracted. This will reduce the cost of console calls.
- SQLite ``BaseConnection::getIndexData()`` now can return pseudo index named ``PRIMARY`` for `AUTOINCREMENT` column, and each returned index data has ``type`` property.

Changes
*******
Expand Down
2 changes: 2 additions & 0 deletions user_guide_src/source/database/metadata.rst
Original file line number Diff line number Diff line change
Expand Up @@ -121,6 +121,8 @@ The key types may be unique to the database you are using.
For instance, MySQL will return one of primary, fulltext, spatial, index or unique
for each key associated with a table.

SQLite3 returns a pseudo index named ``PRIMARY``. But it is a special index, and you can't use it in your SQL commands.

$db->getForeignKeyData()
------------------------

Expand Down

0 comments on commit 9755623

Please sign in to comment.