diff --git a/.gitignore b/.gitignore new file mode 100644 index 0000000..bceb854 --- /dev/null +++ b/.gitignore @@ -0,0 +1,48 @@ +# Bootstrapping # +################# +/node_modules +/public/hot +/public/storage +/storage/*.key +/vendor +.env +.env.backup +.phpunit.result.cache +Homestead.json +Homestead.yaml +npm-debug.log +yarn-error.log + +# OS generated files # +###################### +.DS_Store +.DS_Store? +._* +.Spotlight-V100 +.Trashes +Icon? +ehthumbs.db +Thumbs.db +.directory + +# Tool specific files # +####################### +# vim +*~ +*.swp +*.swo +# sublime text & textmate +*.sublime-* +*.stTheme.cache +*.tmlanguage.cache +*.tmPreferences.cache +# Eclipse +.settings/* +# JetBrains, aka PHPStorm, IntelliJ IDEA +.idea/* +# NetBeans +nbproject/* +# Visual Studio Code +.vscode +# Sass preprocessor +.sass-cache/ \ No newline at end of file diff --git a/README.md b/README.md index 2ec1a1e..9ac1813 100644 --- a/README.md +++ b/README.md @@ -1,50 +1,359 @@ # php-libsqlitedriver -This library provides abstractions for parameter binding and result retrieval on SQLite(-like) databases in PHP. It is built on top of PHP [`SQLite3`](https://www.php.net/manual/en/book.sqlite3.php). +This library provides abstraction methods for common operations on SQLite databases like `SELECT`, `UPDATE`, and `INSERT` using method chaining for the various SQLite features. -## Install with Composer +For example: +```php +SQLite->for(string $table) + ->with(?array $model) + ->where(?array ...$conditions) + ->order(?array $order_by) + ->limit(int|array|null $limit) + ->select(array $columns): array|bool; +``` +which would be equivalent to the following in SQLite: +```sql +SELECT $columns FROM $table WHERE $filter ORDER BY $order_by LIMIT $limit; +``` + +> [!IMPORTANT] +> This library is built on top of the PHP [`SQLite3 Extension`](https://www.php.net/manual/en/book.sqlite3.php) and requires PHP 8.0 or newer. + +## Install from composer ``` -composer require victorwesterlund/libsqlitedriver +composer require victorwesterlund/libSQLitedriver ``` ```php use libsqlitedriver/SQLite; ``` -## Usage +# Example / Documentation -Connect to a SQLite database +Available statements +Statement|Method +--|-- +`SELECT`|[`select()`](#select) +`UPDATE`|[`update()`](#update) +`INSERT`|[`insert()`](#insert) +`DELETE`|[`delete()`](#delete) +`WHERE`|[`where()`](#where) +`ORDER BY`|[`order()`](#order-by) +`LIMIT`|[`limit()`](#limit) + +---- + +`Example table name: beverages` +id|beverage_type|beverage_name|beverage_size +--|--|--|-- +0|coffee|cappuccino|10 +1|coffee|black|15 +2|tea|green|10 +3|tea|black|15 ```php -use libsqlitedriver/SQLite; +use libSQLitedriver\SQLite; -// You can also use ":memory:" to connect to an SQLite database in RAM -$db = new SQLite("./database.db"); +// Pass through: https://www.php.net/manual/en/sqlite3.construct.php +$db = new SQLite($filename = ":memory:"); ``` -Return matching rows from query (array of arrays) +All executor methods [`select()`](#select), [`update()`](#update), and [`insert()`](#insert) will return a [`SQLite3Result`](https://www.php.net/manual/en/class.SQLitei-result.php) object or boolean. + +# FOR ```php -$sql = "SELECT foo FROM table WHERE bar = ? AND biz = ?; +SQLite->for( + string $table +): self; +``` -$response = $db->return_array($sql, [ - "parameter_1", - "parameter_2 +All queries start by chaining the `for(string $table)` method. This will define which database table the current query should be executed on. + +*Example:* +```php +SQLite->for("beverages")->select("beverage_type"); +``` + +# SELECT + +Chain `SQLite->select()` anywhere after a [`SQLite->for()`](#for) to retrieve columns from a database table. + +Pass an associative array of strings, CSV string, or null to this method to filter columns. + +```php +SQLite->select( + array|string|null $columns +): SQLite3Result|bool; +``` + +In most cases you probably want to select with a constraint. Chain the [`where()`](#where) method before `select()` to filter the query + +### Example +```php +$beverages = SQLite->for("beverages")->select(["beverage_name", "beverage_size"]); // SELECT beverage_name, beverage_size FROM beverages +``` +``` +[ + [ + "beverage_name" => "cappuccino", + "beverage_size" => 10 + ], + [ + "beverage_name" => "black", + "beverage_size" => 15 + ], + // ...etc +] +``` + +## Flatten array to single dimension + +If you don't want an array of arrays and would instead like to access each key value pair directly. Chain the `SQLite->flatten()` anywhere before `SQLite->select()`. +This will return the key value pairs of the first entry directly. + +> **Note** +> This method will not set `LIMIT 1` for you. It is recommended to chain `SQLite->limit(1)` anywhere before `SQLite->select()`. [You can read more about it here](https://github.com/VictorWesterlund/php-libSQLitedriver/issues/14) + +```php +$coffee = SQLite->for("beverages")->limit(1)->flatten()->select(["beverage_name", "beverage_size"]); // SELECT beverage_name, beverage_size FROM beverages WHERE beverage_type = "coffee" LIMIT 1 +``` +```php +[ + "beverage_name" => "cappuccino", + "beverage_size" => 10 +] +``` + +# INSERT + +Chain `SQLite->insert()` anywhere after a [`SQLite->for()`](#for) to append a new row to a database table. + +Passing a sequential array to `insert()` will assume that you wish to insert data for all defined columns in the table. Pass an associative array of `[column_name => value]` to INSERT data for specific columns (assuming the other columns have a [DEFAULT](https://dev.SQLite.com/doc/refman/8.0/en/data-type-defaults.html) value defined). + +```php +SQLite->insert( + // Array of values to INSERT + array $values +): SQLite3Result|bool +// Returns true if row was inserted +``` + +#### Example + +```php +SQLite->for("beverages")->insert([ + null, + "coffee", + "latte", + 10 +]); +// INSERT INTO beverages VALUES (null, "coffee", "latte", 10); +``` +``` +true +``` + +# DELETE + +Chain `SQLite->delete()` anywhere after a [`SQLite->for()`](#for) to remove a row or rows from the a database table. + +```php +SQLite->delete( + array ...$conditions +): SQLite3Result|bool +// Returns true if at least one row was deleted +``` + +This method takes at least one [`SQLite->where()`](#where)-syntaxed argument to determine which row or rows to delete. Refer to the [`SQLite->where()`](#where) section for more information. + +#### Example + +```php +SQLite->for("beverages")->insert([ + null, + "coffee", + "latte", + 10 +]); +// INSERT INTO beverages VALUES (null, "coffee", "latte", 10); +``` +``` +true +``` + +# UPDATE + +Chain `SQLite->update()` anywhere after a [`SQLite->for()`](#for) to modify existing rows in a database table. + +```php +SQLite->update( + // Key, value array of column names and values to update + array $fields, +): SQLite3Result|bool; +// Returns true if at least 1 row was changed +``` + +### Example +```php +SQLite->for("beverages")->update(["beverage_size" => 10]); // UPDATE beverages SET beverage_size = 10 +``` +```php +true +``` + +In most cases you probably want to UPDATE against a constaint. Chain a [`where()`](#where) method before [`SQLite->update()`](#update) to set constraints + + +# WHERE + +Filter a [`SQLite->select()`](#select) or [`SQLite->update()`](#update) method by chaining the `SQLite->where()` method anywhere before it. The [`SQLite->delete()`](#delete) executor method also uses the same syntax for its arguments. + +Each key, value pair will be `AND` constrained against each other. + +```php +SQLite->where( + ?array ...$conditions +): self; +``` + +### Example +```php +$coffee = SQLite->for("beverages")->where(["beverage_type" => "coffee"])->select(["beverage_name", "beverage_size"]); // SELECT beverage_name, beverage_size FROM beverages WHERE (beverage_type = "coffee"); +``` +```php +[ + [ + "beverage_name" => "cappuccino", + "beverage_size" => 10 + ], + [ + "beverage_name" => "black", + "beverage_size" => 15 + ] +] +``` + +## Capture groups + +### AND + +Add additional key value pairs to an array passed to `where()` and they will all be compared as AND with each other. + +```php +SQLite->where([ + "beverage_type" => "coffee", + "beverage_size" => 15 +]); +``` +```sql +WHERE (beverage_type = 'coffee' AND beverage_size = 15) +``` + +### OR + +Passing an additional array of key values as an argument will OR it with all other arrays passed. + +```php +$filter1 = [ + "beverage_type" => "coffee", + "beverage_size" => 15 ]; -// Example $response with two matching rows: [["hello"],["world"]] -``` - -Return boolean if query matched at least one row, or if != `SELECT` query was sucessful - -```php -$sql = "INSERT INTO table (foo, bar) VALUES (?, ?); - -$response = $db->return_bool($sql, [ - "baz", - "qux" +$filter2 = [ + "beverage_type" => "tea", + "beverage_name" => "black" ]; -// Example $response if sucessful: true +SQLite->where($filter1, $filter2, ...); ``` +```sql +WHERE (beverage_type = 'coffee' AND beverage_size = 15) OR (beverage_type = 'tea' AND beverage_name = 'black') +``` + +# ORDER BY + +Chain the `SQLite->order()` method before a [`SQLite->select()`](#select) statement to order by a specific column + +```php +SQLite->order( + ?array $order_by +): self; +``` + +```php +$coffee = SQLite->for("beverages")->order(["beverage_name" => "ASC"])->select(["beverage_name", "beverage_size"]); // SELECT beverage_name, beverage_size FROM beverages ORDER BY beverage_name ASC +``` +```php +[ + [ + "beverage_name" => "tea", + "beverage_size" => 10 + ], + [ + "beverage_name" => "tea", + "beverage_size" => 15 + ], + // ...etc for "beverage_name = coffee" +] +``` + +# LIMIT + +Chain the `limit()` method before a [`SQLite->select()`](#select) statement to limit the amount of columns returned + +```php +SQLite->limit( + ?int $limit, + ?int $offset = null +): self; +``` + +> **Note** +> You can also flatten to a single dimensional array from the first entity by chaining [`SQLite->flatten()`](#flatten-array-to-single-dimension) + +## Passing a single integer argument +This will simply `LIMIT` the results returned to the integer passed + +```php +$coffee = SQLite->for("beverages")->limit(1)->select(["beverage_name", "beverage_size"]); // SELECT beverage_name, beverage_size FROM beverages WHERE beverage_type = "coffee" LIMIT 1 +``` +```php +[ + [ + "beverage_name" => "cappuccino", + "beverage_size" => 10 + ] +] +``` + +## Passing two integer arguments +This will `OFFSET` and `LIMIT` the results returned. The first argument will be the `LIMIT` and the second argument will be its `OFFSET`. + +```php +$coffee = SQLite->for("beverages")->limit(3, 2)->select(["beverage_name", "beverage_size"]); // SELECT beverage_name, beverage_size FROM beverages LIMIT 3 OFFSET 2 +``` +```php +[ + [ + "beverage_name" => "tea", + "beverage_size" => 10 + ], + [ + "beverage_name" => "tea", + "beverage_size" => 15 + ], + // ...etc +] +``` + +---- + +# Restrict affected/returned database columns to table model + +Chain and pass an array to `SQLite->with()` before a `select()`, `update()`, or `insert()` method to limit which columns will be returned/affected. It will use the **values** of the array so it can be either sequential or associative. + +**This method will cause `select()`, `update()`, and `insert()` to ignore any columns that are not present in the passed table model.** + +You can remove an already set table model by passing `null` to `SQLite->with()` diff --git a/src/DatabaseDriver.php b/src/DatabaseDriver.php new file mode 100644 index 0000000..0507021 --- /dev/null +++ b/src/DatabaseDriver.php @@ -0,0 +1,53 @@ +prepare($query); + + // Format optional placeholder "?" with values + if (!empty($values)) { + // Move single arguemnt into array + if (!is_array($values)) { + $values = [$values]; + } + + foreach ($values as $k => $value) { + $statement->bindValue($k + 1, $value); // Index starts at 1 + } + } + + // Return SQLite3Result object + return $statement->execute(); + } + + /* ---- */ + + // Return rows as assoc array + #[\ReturnTypeWillChange] + public function exec(string $sql, mixed $params = null): array { + $results = []; + $query = $this->run_query($sql, $params); + + while ($result = $query->fetchArray(SQLITE3_ASSOC)) { + $results[] = $result; + } + + return $results; + } + + // Returns true if rows were returned + public function exec_bool(string $sql, mixed $params = null): bool { + $query = $this->run_query($sql, $params); + return $query->numColumns() > 0; + } + } \ No newline at end of file diff --git a/src/SQLite.php b/src/SQLite.php index 6e9653a..8b6b940 100644 --- a/src/SQLite.php +++ b/src/SQLite.php @@ -1,119 +1,240 @@ db_path = $db; + use \Exception; + use \victorwesterlund\xEnum; - // Run .sql file on first run of persistant db - $run_init = false; + use libsqlitedriver\Driver\DatabaseDriver; - // Set path to persistant db - if ($this->db_path !== ":memory:") { - // Get path to database without filename - $path = explode("/", $this->db_path); - array_pop($path); - $path = implode("/", $path); + require_once "DatabaseDriver.php"; - // Check write permissions of database - if (!is_writeable($path)) { - throw new \Error("Permission denied: Can not write to directory '{$path}'"); - } - - // Database doesn't exist and an init file as been provided - $run_init = !file_exists($db) && $init ? true : $run_init; - } - - parent::__construct($db); + // Interface for MySQL_Driver with abstractions for data manipulation + class SQLite extends DatabaseDriver { + private string $table; + private ?array $model = null; - if ($run_init) { - $this->init_db($init); + private bool $flatten = false; + private ?string $order_by = null; + private ?string $filter_sql = null; + private array $filter_values = []; + private int|string|null $limit = null; + + // Pass constructor arguments to driver + function __construct(string $database) { + parent::__construct($database); + } + + private function throw_if_no_table() { + if (!$this->table) { + throw new Exception("No table name defined"); } } - // Execute a prepared statement and SQLite3Result object - private function run_query(string $query, mixed $values = []): \SQLite3Result|bool { - $statement = $this->prepare($query); - - // Format optional placeholder "?" with values - if (!empty($values)) { - // Move single arguemnt into array - if (!is_array($values)) { - $values = [$values]; - } - - foreach ($values as $k => $value) { - $statement->bindValue($k + 1, $value); // Index starts at 1 - } - } - - // Return SQLite3Result object - return $statement->execute(); - } - - // Execute SQL from a file - private function exec_file(string $file): bool { - return $this->exec(file_get_contents($file)); + // Return value(s) that exist in $this->model + private function in_model(string|array $columns): ?array { + // Place string into array + $columns = is_array($columns) ? $columns : [$columns]; + // Return columns that exist in table model + return array_filter($columns, fn($col): string => in_array($col, $this->model)); } /* ---- */ - // Create comma separated list (CSV) from array - private static function csv(array $values): string { - return implode(",", $values); + // Use the following table name + public function for(string $table): self { + $this->table = $table; + return $this; } - // Create CSV from columns - public static function columns(array|string $columns): string { - return is_array($columns) - ? (__CLASS__)::csv($columns) - : $columns; + // Restrict query to array of column names + public function with(?array $model = null): self { + // Remove table model if empty + if (!$model) { + $this->model = null; + return $this; + } + + // Reset table model + $this->model = []; + + foreach ($model as $k => $v) { + // Column values must be strings + if (!is_string($v)) { + throw new Exception("Key {$k} must have a value of type string"); + } + + // Append column to model + $this->model[] = $v; + } + + return $this; } - // Return CSV of '?' for use with prepared statements - public static function values(array|string $values): string { - return is_array($values) - ? (__CLASS__)::csv(array_fill(0, count($values), "?")) - : "?"; + // Create a WHERE statement from filters + public function where(array ...$conditions): self { + $values = []; + $filters = []; + + // Group each condition into an AND block + foreach ($conditions as $condition) { + $filter = []; + + // Move along if the condition is empty + if (empty($condition)) { + continue; + } + + // Create SQL string and append values to array for prepared statement + foreach ($condition as $col => $value) { + if ($this->model && !$this->in_model($col)) { + continue; + } + + // Create SQL for prepared statement + $filter[] = "`{$col}` = ?"; + // Append value to array with all other values + $values[] = $value; + } + + // AND together all conditions into a group + $filters[] = "(" . implode(" AND ", $filter) . ")"; + } + + // Do nothing if no filters were set + if (empty($filters)) { + return $this; + } + + // OR all filter groups + $this->filter_sql = implode(" OR ", $filters); + // Set values property + $this->filter_values = $values; + + return $this; + } + + // Return SQL LIMIT string from integer or array of [offset => limit] + public function limit(int|array $limit): self { + // Set LIMIT without range directly as integer + if (is_int($limit)) { + $this->limit = $limit; + return $this; + } + + // Use array key as LIMIT range start value + $offset = (int) array_keys($limit)[0]; + // Use array value as LIMIT range end value + $limit = (int) array_values($limit)[0]; + + // Set limit as SQL CSV + $this->limit = "{$offset},{$limit}"; + return $this; + } + + // Flatten returned array to first entity if set + public function flatten(bool $flag = true): self { + $this->flatten = $flag; + return $this; + } + + // Return SQL SORT BY string from assoc array of columns and direction + public function order(array $order_by): self { + // Create CSV from columns + $sql = implode(",", array_keys($order_by)); + // Create pipe DSV from values + $sql .= " " . implode("|", array_values($order_by)); + + $this->order_by = $sql; + return $this; } /* ---- */ - // Get result as column indexed array - public function return_array(string $query, mixed $values = []): array { - $result = $this->run_query($query, $values); - $rows = []; + // Create Prepared Statament for SELECT with optional WHERE filters + public function select(array|string|null $columns = null): array|bool { + $this->throw_if_no_table(); - if (is_bool($result)) { - return []; + // Create array of columns from CSV + $columns = is_array($columns) || is_null($columns) ? $columns : explode(",", $columns); + + // Filter columns that aren't in the model if defiend + if ($columns && $this->model) { + $columns = $this->in_model($columns); } - // Get each row from SQLite3Result - while ($row = $result->fetchArray(SQLITE3_ASSOC)) { - $rows[] = $row; + // Create CSV from columns or default to SQL NULL as a string + $columns_sql = $columns ? implode(",", $columns) : "NULL"; + + // Create LIMIT statement if argument is defined + $limit_sql = !is_null($this->limit) ? " LIMIT {$this->limit}" : ""; + + // Create ORDER BY statement if argument is defined + $order_by_sql = !is_null($this->order_by) ? " ORDER BY {$this->order_by}" : ""; + + // Get array of SQL WHERE string and filter values + $filter_sql = !is_null($this->filter_sql) ? " WHERE {$this->filter_sql}" : ""; + + // Interpolate components into an SQL SELECT statmenet and execute + $sql = "SELECT {$columns_sql} FROM {$this->table}{$filter_sql}{$order_by_sql}{$limit_sql}"; + + // No columns were specified, return true if query matched rows + if (!$columns) { + return $this->exec_bool($sql, $this->filter_values); } - return $rows; + // Return array of matched rows + $exec = $this->exec($sql, $this->filter_values); + // Return array if exec was successful. Return as flattened array if flag is set + return empty($exec) || !$this->flatten ? $exec : $exec[0]; } - // Get only whether a query was sucessful or not - public function return_bool(string $query, mixed $values = []): bool { - $result = $this->run_query($query, $values); + // Create Prepared Statement for UPDATE using PRIMARY KEY as anchor + public function update(array $entity): bool { + $this->throw_if_no_table(); - if (is_bool($result)) { - return $result; + // Make constraint for table model if defined + if ($this->model) { + foreach (array_keys($entity) as $col) { + // Throw if column in entity does not exist in defiend table model + if (!in_array($col, $this->model)) { + throw new Exception("Column key '{$col}' does not exist in table model"); + } + } } - // Get first row or return false - $row = $result->fetchArray(SQLITE3_NUM); - return $row !== false ? true : false; + // Create CSV string with Prepared Statement abbreviations from length of fields array. + $changes = array_map(fn($column) => "{$column} = ?", array_keys($entity)); + $changes = implode(",", $changes); + + // Get array of SQL WHERE string and filter values + $filter_sql = !is_null($this->filter_sql) ? " WHERE {$this->filter_sql}" : ""; + + $values = array_values($entity); + // Append filter values if defined + if ($this->filter_values) { + array_push($values, ...$this->filter_values); + } + + // Interpolate components into an SQL UPDATE statement and execute + $sql = "UPDATE {$this->table} SET {$changes} {$filter_sql}"; + return $this->exec_bool($sql, $values); } - /* ---- */ + // Create Prepared Statemt for INSERT + public function insert(array $values): bool { + $this->throw_if_no_table(); - // Initialize a fresh database with SQL from file - private function init_db(string $init) { - return $this->exec_file($init); + // A value for each column in table model must be provided + if ($this->model && count($values) !== count($this->model)) { + throw new Exception("Values length does not match columns in model"); + } + + // Create CSV string with Prepared Statement abbreviatons from length of fields array. + $values_stmt = implode(",", array_fill(0, count($values), "?")); + + // Interpolate components into an SQL INSERT statement and execute + $sql = "INSERT INTO {$this->table} VALUES ({$values_stmt})"; + return $this->exec_bool($sql, $values); } - } + } \ No newline at end of file