/*! \page database_page Databases
\section types_of_databases Database Options
Autopsy currently allows either \ref sqlite_db or \ref postgresql_db as the back-end database system for a case. Any module you write could be used with either as the backend database, at the user's discretion.
\subsection sqlite_db SQLite
- SQLite 3 or newer
- Used for Single-user cases
- Built-in
- No configuration required
- Databases are stored locally
\subsection postgresql_db PostgreSQL
- PostgreSQL 9.4.1 or newer
- Used for Multi-user cases
- An accessible instance of PostgreSQL must be running (on a server, or locally)
- Proper configuration to connect to this instance of PostgreSQL must be entered in Tools, Options, Multi-User options
- Databases are stored within PostgreSQL, wherever it happens to be running
\subsection which_db Which Database is my Module Accessing?
In an Autopsy Module, you can check the database type currently in use with the following code snippet:
\code{.java}
Case currentCase = Case.getCurrentCase();
if (currentCase.getCaseType() == Case.CaseType.MULTI_USER_CASE)
{
// PostgreSQL in use
}
else
{
// SQLite in use
}
\endcode
\section db_user_calls TSK methods to Query the Database With User-Supplied SQL
The following SleuthkitCase methods are available for the user to supply all of, or a portion of, a SQL query.
\code{.java}
ArrayList getMatchingAttributes(String whereClause)
ArrayList getMatchingArtifacts(String whereClause)
long countFilesWhere(String sqlWhereClause)
List findAllFilesWhere(String sqlWhereClause)
List findAllFileIdsWhere(String sqlWhereClause)
CaseDbQuery executeQuery(String query)
List findFilesWhere(String sqlWhereClause) [deprecated]
ResultSet runQuery(String query) [deprecated]
void closeRunQuery(ResultSet resultSet) [deprecated]
\endcode
The majority of them only allow the user to specify a WHERE clause, determining which records to SELECT.
The following example finds all the .txt files in the case:
\code{.java}
List files = sk.findAllFilesWhere("name LIKE '%.txt'");
\endcode
\section db_pitfalls_to_avoid How to Avoid Pitfalls When Using the Query Methods
Because there are multiple backend databases, care must be taken to use strict SQL. When things must be different between database types, use \ref which_db to determine which database type is currently in use and create the proper SQL statements.
- Test your module with both types of databases. They behave differently and will give you different resulting output order.
- Do not use INSERT OR REPLACE INTO. It does not exist in PostgreSQL.
- Do not use INSERT OR IGNORE INTO. It does not exist in PostgreSQL.
- SQLite and PostgreSQL have different defaults on what order they will return records in, so you want to fully specify ORDER BY clauses for both database types. Example:
\code{.java}
String orderByClause;
if (currentCase.getCaseType() == Case.CaseType.MULTI_USER_CASE)
{
orderByClause = "ORDER BY att.value_text, ASC NULLS FIRST"; //PostgreSQL
}
else
{
orderByClause = "ORDER BY att.value_text ASC"; //SQLite
}
\endcode
- Do not use backticks. PostgreSQL does not use them like SQLite does.
- Use only single quotes to quote values. Do not use double quotes for this. Quoting values is not required.
\code{.java}
SELECT * FROM tsk_files WHERE has_path = "1" // Bad example
SELECT * FROM tsk_files WHERE has_path = '1' // Good example
SELECT * FROM tsk_files WHERE has_path = 1 // Good example
\endcode
- Use only double quotes to quote column names. Do not use single quotes for this. Quoting column names is not required.
\code{.java}
SELECT 'obj_id' FROM tsk_files WHERE has_path = 1 // Bad example
SELECT "obj_id" FROM tsk_files WHERE has_path = 1 // Good example
SELECT obj_id FROM tsk_files WHERE has_path = 1 // Good example
\endcode
- PostgreSQL compares are case-sensitive. Always specify what type of compare you want. UPPER(), LOWER(), ILIKE etc can help with that.
\code{.java}
SELECT * from people WHERE first_name LIKE '%somename%' // Will be case sensitive in PostgreSQL, not in SQLite
SELECT * from people WHERE first_name ILIKE '%somename%' // Works in PostgreSQL, does not exist in SQLite
SELECT * from people WHERE LOWER(first_name) LIKE LOWER('%somename%') // Not case sensitive in either database
\endcode
- Do not use || and && to connect logical clauses. This does not exist in PostgreSQL. Use OR and AND instead.
\code{.java}
SELECT COUNT(*) FROM tsk_files WHERE dir_type = '5' && md5 IS NULL || size > '0' // Bad Example
SELECT COUNT(*) FROM tsk_files WHERE dir_type = '5' AND md5 IS NULL OR size > '0' // Good Example
\endcode
- Do not use COLLATE NOCASE to order output. This does not exist in PostgreSQL. Use LOWER() or UPPER() instead.
\code{.java}
ORDER BY tsk_files.dir_type, tsk_files.name COLLATE NOCASE // Bad Example
ORDER BY tsk_files.dir_type, LOWER(tsk_files.name) // Good Example
\endcode
- Do not insert [NUL characters](http://en.wikipedia.org/wiki/Null_character) into the database as UTF-8 (NUL characters are not NULL fields). Translate NUL characters to the [SUB character](http://en.wikipedia.org/wiki/Substitute_character) with the following instead:
\code{.java}
private String replaceNulls(String text);
\endcode
- In ORDER BY clauses, PostgreSQL ignores leading dashes. Given the following data, you will see the following two sort orders for the different databases.
| Data | PostgreSQL sort order | SQLite sort order|
|:--------:|:------------------------:|:------------------:|
|Alpha | Alpha | -Bravo |
|-Bravo | -Bravo | Alpha |
|Charlie | Charlie | Charlie |
To force PostgreSQL to not ignore leading dashes, convert strings to SQL_ASCII before sorting by them. This is done with convert_to(), but it only exists in PostgreSQL.
\code{.java}
ORDER BY some_value // Bad example
ORDER BY convert_to(some_value, 'SQL_ASCII') // Good example
\endcode
With the code above, using SQL_ASCII encoding, the following results are seen:
| Data | PostgreSQL sort order | SQLite sort order|
|:--------:|:------------------------:|:------------------:|
|Alpha | -Bravo | -Bravo |
|-Bravo | Alpha | Alpha |
|Charlie | Charlie | Charlie |
- PostgreSQL sorts NULLs last for ASC and first for DESC. SQLite does the opposite. PostgreSQL allows you to control the NULL sort order with NULLS FIRST or NULLS LAST
\code{.java}
ORDER BY att.value_text ASC // SQLite example, will give different ordering in PostgreSQL
ORDER BY convert_to(att.value_text, 'SQL_ASCII') ASC NULLS FIRST // PostgreSQL example, does not exist in SQLite
\endcode
*/