Skip to content

Commit

Permalink
Merge pull request #9 from nathanjrobertson/multiquery
Browse files Browse the repository at this point in the history
Allow query attribute to optionally take a list of queries
  • Loading branch information
tvdijen committed Mar 14, 2024
2 parents 4409ebb + 3d7112c commit 4c494f6
Show file tree
Hide file tree
Showing 6 changed files with 384 additions and 62 deletions.
4 changes: 4 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
@@ -1,3 +1,7 @@
# SimpleSAMLphp `sqlauth` module

This is a authentication module for authenticating a user against a SQL database. See [the documentation](https://simplesamlphp.org/docs/contrib_modules/sqlauth/sql.html) for details of how to use this module.

![Build Status](https://github.com/simplesamlphp/simplesamlphp-module-sqlauth/workflows/CI/badge.svg?branch=master)
[![Coverage Status](https://codecov.io/gh/simplesamlphp/simplesamlphp-module-sqlauth/branch/master/graph/badge.svg)](https://codecov.io/gh/simplesamlphp/simplesamlphp-module-sqlauth)
[![Scrutinizer Code Quality](https://scrutinizer-ci.com/g/simplesamlphp/simplesamlphp-module-sqlauth/badges/quality-score.png?b=master)](https://scrutinizer-ci.com/g/simplesamlphp/simplesamlphp-module-sqlauth/?branch=master)
Expand Down
100 changes: 88 additions & 12 deletions docs/sql.md
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,6 @@

This is a authentication module for authenticating a user against a SQL database.


Options
-------

Expand All @@ -14,24 +13,20 @@ Options
`username`
: The username which should be used when connecting to the database server.


`password`
: The password which should be used when connecting to the database server.

`query`
: The SQL query which should be used to retrieve the user.
The parameters :username and :password are available.
If the username/password is incorrect, the query should return no rows.
The name of the columns in resultset will be used as attribute names.
If the query returns multiple rows, they will be merged into the attributes.
Duplicate values and NULL values will be removed.
: The SQL query or queries which should be used to authenticate the user and retrieve their attributes.

Writing a Query / Queries
-------------------------

Examples
--------
A `query` can be either a single string with an SQL statement, or an array of queries, run in order. That single string (or the first query in the array) is the "authentication query" - the parameters `:username` and `:password` are available and should be evaluated by the query for authenticaion purposes. If the username/password is incorrect, the "authentication query" should return no rows. The rows returned represent attributes to be returned.

Database layout used in some of the examples:
Taking this example schema:

```sql
CREATE TABLE users (
uid VARCHAR(30) NOT NULL PRIMARY KEY,
password TEXT NOT NULL,
Expand All @@ -45,7 +40,83 @@ Database layout used in some of the examples:
groupname VARCHAR(30) NOT NULL,
UNIQUE(uid, groupname)
);

```

a basic entry with a single SQL string in `authsources.php` might look like this (PostgreSQL, SHA512 of salt + password, base64 encoded with the salt stored in an independent column):

```php
'example-sql' => [
'sqlauth:SQL',
'dsn' => 'pgsql:host=postgresql;port=5432;dbname=simplesaml',
'username' => 'simplesaml',
'password' => 'secretpassword',
'query' => "select uid, givenName as \"givenName\", email from users where uid=:username and password=encode(sha512(concat((select salt from users where uid=1), :password)::bytea), 'base64')",
],
```

It's worth repeating at this point that if authentication is unsuccessful (ie. the username / password pair don't match), this query **must** return zero rows. Assuming the username / password pair provided was a match, the name of the columns in result set will be used as attribute names. In the above case, PostgreSQL lowercases the names by default, which we correct with the "as" clause. The result might look like this:

| Attribute Name | Attribute Value |
|----------------|-----------------|
| uid | [ bobsmith ] |
| givenName | [ Bob ] |
| email | [ bob@example.com ] |

You'll likely need to collect attributes from more than just the table with the username and password hash. There are two supported ways to do this: table joins on your authentication query, or providing an array of queries for the `query` parameter instead of just the single query.

A basic example of the single query with join:

```php
'example-sql' => [
'sqlauth:SQL',
'dsn' => 'pgsql:host=postgresql;port=5432;dbname=simplesaml',
'username' => 'simplesaml',
'password' => 'secretpassword',
'query' => "select u.uid, u.givenName as \"givenName\", ug.groupname as \"groupName\" from users u left join usergroups ug on (u.uid=ug.uid) where u.uid=:username and u.password=encode(sha512(concat((select salt from users where uid=1), :password)::bytea), 'base64')",
],
```

which can also be written as:

```php
'example-sql' => [
'sqlauth:SQL',
'dsn' => 'pgsql:host=postgresql;port=5432;dbname=simplesaml',
'username' => 'simplesaml',
'password' => 'secretpassword',
'query' => [
"select uid, givenName as \"givenName\", email from users where uid=:username and password=encode(sha512(concat((select salt from users where uid=1), :password)::bytea), 'base64')",
"select groupName as \"groupName\" from usergroups where uid=:username",
],
"select u.uid, u.givenName, ug.groupname from users u left join usergroups ug on (u.uid=ug.uid) where u.uid=:username and u.password=encode(sha512(concat((select salt from users where uid=1), :password)::bytea), 'base64')",
],
```

both of which will return attributes like:

| Attribute Name | Attribute Value |
|----------------|-----------------|
| uid | [ bobsmith ] |
| givenName | [ Bob ] |
| email | [ bob@example.com ] |
| groupName | [ users, staff ] |

For simple cases, the single query will suffice. As the number of tables you are joining to collate your attributes gets higher, then using the query list will make your configuration more maintainable.

In summary:

- If the single string query (or the first query if it's an array of queries) returns no rows, that indicates authentication failed.
- The single string query (or the first query if it's an array of queries) should use the passed `:username` and `:password` query parameters to do authentication.
- If more than one query is desirable or required to get all of the attributes, you can specify an array of queries. In this case, the result set of the second and subsequent queries in that array provide attributes only - only the first query is used to determine if the username/password is correct or not, and as such :password is only passed to the first query in the list.
- If `query` is an array of queries, because the second and subsequent queries have no role in authentication, these queries may return no rows, simply indicating that query should have no effect on the final returned attribute set.
- If any query returns multiple rows, they will be merged into the attributes.
- If multiple queries return the same column names, they will also be merged into the same attributes.
- Duplicate values and NULL values will be removed.

Further Examples
----------------

```sql
Example query - SHA256 of salt + password, with the salt stored in an independent column, MySQL server:

SELECT uid, givenName, email, eduPersonPrincipalName
Expand All @@ -58,9 +129,11 @@ Example query - SHA256 of salt + password, with the salt stored in an independen
),
256
)
```

Example query - SHA256 of salt + password, with the salt stored in an independent column. Multiple groups, MySQL server:

```sql
SELECT users.uid, givenName, email, eduPersonPrincipalName, groupname AS groups
FROM users LEFT JOIN usergroups ON users.uid = usergroups.username
WHERE users.uid = :username
Expand All @@ -71,9 +144,11 @@ Example query - SHA256 of salt + password, with the salt stored in an independen
),
256
)
```

Example query - SHA512 of salt + password, stored as salt (32 bytes) + sha256(salt + password) in password-field, PostgreSQL server:

```sql
SELECT uid, givenName, email, eduPersonPrincipalName
FROM users
WHERE username = :username
Expand All @@ -86,6 +161,7 @@ Example query - SHA512 of salt + password, stored as salt (32 bytes) + sha256(sa
),
512
)
```

Security considerations
-----------------------
Expand Down
119 changes: 69 additions & 50 deletions src/Auth/Source/SQL.php
Original file line number Diff line number Diff line change
Expand Up @@ -57,12 +57,12 @@ class SQL extends UserPassBase
private array $options = [];

/**
* The query we should use to retrieve the attributes for the user.
* The query or queries we should use to retrieve the attributes for the user.
*
* The username and password will be available as :username and :password.
* @var string
* @var array
*/
private string $query;
private array $query;

/**
* Constructor for this authentication source.
Expand All @@ -76,7 +76,7 @@ public function __construct(array $info, array $config)
parent::__construct($info, $config);

// Make sure that all required parameters are present.
foreach (['dsn', 'username', 'password', 'query'] as $param) {
foreach (['dsn', 'username', 'password'] as $param) {
if (!array_key_exists($param, $config)) {
throw new Exception('Missing required attribute \'' . $param .
'\' for authentication source ' . $this->authId);
Expand All @@ -90,10 +90,19 @@ public function __construct(array $info, array $config)
}
}

// Query can be a single query or an array of queries.
if (!array_key_exists('query', $config)) {
throw new Exception('Missing required attribute \'query\' ' .
'for authentication source ' . $this->authId);
} elseif (is_array($config['query']) && (count($config['query']) < 1)) {
throw new Exception('Required attribute \'query\' is an empty ' .
'list of queries for authentication source ' . $this->authId);
}

$this->dsn = $config['dsn'];
$this->username = $config['username'];
$this->password = $config['password'];
$this->query = $config['query'];
$this->query = is_string($config['query']) ? [$config['query']] : $config['query'];
if (isset($config['options'])) {
$this->options = $config['options'];
}
Expand Down Expand Up @@ -154,61 +163,71 @@ private function connect(): PDO
protected function login(string $username, string $password): array
{
$db = $this->connect();
$params = ['username' => $username, 'password' => $password];
$attributes = [];

try {
$sth = $db->prepare($this->query);
} catch (PDOException $e) {
throw new Exception('sqlauth:' . $this->authId .
': - Failed to prepare query: ' . $e->getMessage());
}

try {
$sth->execute(['username' => $username, 'password' => $password]);
} catch (PDOException $e) {
throw new Exception('sqlauth:' . $this->authId .
': - Failed to execute query: ' . $e->getMessage());
}
$numQueries = count($this->query);
for ($x = 0; $x < $numQueries; $x++) {
try {
$sth = $db->prepare($this->query[$x]);
} catch (PDOException $e) {
throw new Exception('sqlauth:' . $this->authId .
': - Failed to prepare query: ' . $e->getMessage());
}

try {
$data = $sth->fetchAll(PDO::FETCH_ASSOC);
} catch (PDOException $e) {
throw new Exception('sqlauth:' . $this->authId .
': - Failed to fetch result set: ' . $e->getMessage());
}
try {
$sth->execute($params);
} catch (PDOException $e) {
throw new Exception('sqlauth:' . $this->authId .
': - Failed to execute query: ' . $e->getMessage());
}

Logger::info('sqlauth:' . $this->authId . ': Got ' . count($data) .
' rows from database');
try {
$data = $sth->fetchAll(PDO::FETCH_ASSOC);
} catch (PDOException $e) {
throw new Exception('sqlauth:' . $this->authId .
': - Failed to fetch result set: ' . $e->getMessage());
}

if (count($data) === 0) {
// No rows returned - invalid username/password
Logger::error('sqlauth:' . $this->authId .
': No rows in result set. Probably wrong username/password.');
throw new Error\Error('WRONGUSERPASS');
}
Logger::info('sqlauth:' . $this->authId . ': Got ' . count($data) .
' rows from database');

/* Extract attributes. We allow the resultset to consist of multiple rows. Attributes
* which are present in more than one row will become multivalued. null values and
* duplicate values will be skipped. All values will be converted to strings.
*/
$attributes = [];
foreach ($data as $row) {
foreach ($row as $name => $value) {
if ($value === null) {
continue;
if ($x === 0) {
if (count($data) === 0) {
// No rows returned from first query - invalid username/password
Logger::error('sqlauth:' . $this->authId .
': No rows in result set. Probably wrong username/password.');
throw new Error\Error('WRONGUSERPASS');
}
/* Only the first query should be passed the password, as that is the only
* one used for authentication. Subsequent queries are only used for
* getting attribute lists, so only need the username. */
unset($params['password']);
}

$value = (string) $value;
/* Extract attributes. We allow the resultset to consist of multiple rows. Attributes
* which are present in more than one row will become multivalued. null values and
* duplicate values will be skipped. All values will be converted to strings.
*/
foreach ($data as $row) {
foreach ($row as $name => $value) {
if ($value === null) {
continue;
}

if (!array_key_exists($name, $attributes)) {
$attributes[$name] = [];
}
$value = (string) $value;

if (in_array($value, $attributes[$name], true)) {
// Value already exists in attribute
continue;
}
if (!array_key_exists($name, $attributes)) {
$attributes[$name] = [];
}

if (in_array($value, $attributes[$name], true)) {
// Value already exists in attribute
continue;
}

$attributes[$name][] = $value;
$attributes[$name][] = $value;
}
}
}

Expand Down
3 changes: 3 additions & 0 deletions tests/bootstrap.php
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,9 @@
$projectRoot = dirname(__DIR__);
require_once($projectRoot . '/vendor/autoload.php');

// Load our wrapper class to get around login() being declared protected in SQL.php
require_once($projectRoot . '/tests/src/Auth/Source/SQLWrapper.php');

// Symlink module into ssp vendor lib so that templates and urls can resolve correctly
$linkPath = $projectRoot . '/vendor/simplesamlphp/simplesamlphp/modules/sqlauth';
if (file_exists($linkPath) === false) {
Expand Down
Loading

0 comments on commit 4c494f6

Please sign in to comment.