Add unsafe documentation (#158)

* Add unsafe documentation

* Update README.md

Co-Authored-By: Matt Parsons <parsonsmatt@gmail.com>

* Update README.md

Co-Authored-By: Matt Parsons <parsonsmatt@gmail.com>

* Update README.md

Co-Authored-By: Matt Parsons <parsonsmatt@gmail.com>

* Update README.md

Co-Authored-By: Matt Parsons <parsonsmatt@gmail.com>

* Update README.md

Co-Authored-By: Matt Parsons <parsonsmatt@gmail.com>

* Update README.md

Co-Authored-By: Matt Parsons <parsonsmatt@gmail.com>

* Update README.md

Co-Authored-By: Matt Parsons <parsonsmatt@gmail.com>

* updated Readme.md

* Update README.md

Co-Authored-By: Matt Parsons <parsonsmatt@gmail.com>

* add safety
This commit is contained in:
Jose Duran 2019-10-31 15:34:31 -05:00 committed by Matt Parsons
parent 096a251c39
commit f9f953c89e

145
README.md
View File

@ -243,6 +243,151 @@ There are many differences between SQL syntax and functions supported by differe
In order to use these functions, you need to explicitly import their corresponding modules.
### Unsafe functions, operators and values
Esqueleto doesn't support every possible function, and it can't - many functions aren't available on every RDBMS platform, and sometimes the same functionality is hidden behind different names. To overcome this problem, Esqueleto exports a number of unsafe functions to call any function, operator or value. These functions can be found in Database.Esqueleto.Internal.Sql module.
Warning: the functions discussed in this section must always be used with an explicit type signature,and the user must be careful to provide a type signature that corresponds correctly with the underlying code. The functions have extremely general types, and if you allow type inference to figure everything out for you, it may not correspond with the underlying SQL types that you want. This interface is effectively the FFI to SQL database, so take care!
The most common use of these functions is for calling RDBMS specific or custom functions,
for that end we use `unsafeSqlFunction`. For example, if we wish to consult the postgres
`now` function we could so as follow:
```haskell
postgresTime :: (MonadIO m, MonadLogger m) => SqlWriteT m UTCTime
postgresTime =
result <- select (pure now)
case result of
[x] -> pure x
_ -> error "now() is guaranteed to return a single result"
where
now :: SqlExpr (Value UTCTime)
now = unsafeSqlFunction "now" ()
```
which generates this SQL:
```sql
SELECT now()
```
With the `now` function we could now use the current time of the postgres RDBMS on any query.
Do notice that `now` does not use any arguments, so we use `()` that is an instance of
`UnsafeSqlFunctionArgument` to represent no arguments, an empty list cast to a correct value
will yield the same result as `()`.
We can also use `unsafeSqlFunction` for more complex functions with customs values using
`unsafeSqlValue` which turns any string into a sql value of whatever type we want, disclaimer:
if you use it badly you will cause a runtime error. For example, say we want to try postgres'
`date_part` function and get the day of a timestamp, we could use:
```haskell
postgresTimestampDay :: (MonadIO m, MonadLogger m) => SqlWriteT m Int
postgresTimestampDay =
result <- select (return $ dayPart date)
case result of
[x] -> pure x
_ -> error "dayPart is guaranteed to return a single result"
where
dayPart :: SqlExpr (Value UTCTime) -> SqlExpr (Value Int)
dayPart s = unsafeSqlFunction "date_part" (unsafeSqlValue "\'day\'" :: SqlExpr (Value String) ,s)
date :: SqlExpr (Value UTCTime)
date = unsafeSqlValue "TIMESTAMP \'2001-02-16 20:38:40\'"
```
which generates this SQL:
```sql
SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40')
```
Using `unsafeSqlValue` we were required to also define the type of the value.
Another useful unsafe function is `unsafeSqlCastAs`, which allows us to cast any type
to another within a query. For example, say we want to use our previews `dayPart` function
on the current system time, we could:
```haskell
postgresTimestampDay :: (MonadIO m, MonadLogger m) => SqlWriteT m Int
postgresTimestampDay = do
currentTime <- liftIO getCurrentTime
result <- select (return $ dayPart (toTIMESTAMP $ val currentTime))
case result of
[x] -> pure x
_ -> error "dayPart is guaranteed to return a single result"
where
dayPart :: SqlExpr (Value UTCTime) -> SqlExpr (Value Int)
dayPart s = unsafeSqlFunction "date_part" (unsafeSqlValue "\'day\'" :: SqlExpr (Value String) ,s)
toTIMESTAMP :: SqlExpr (Value UTCTime) -> SqlExpr (Value UTCTime)
toTIMESTAMP = unsafeSqlCastAs "TIMESTAMP"
```
which generates this SQL:
```sql
SELECT date_part('day', CAST('2019-10-28 23:19:39.400898344Z' AS TIMESTAMP))
```
### SQL injection
Esqueleto uses parameterization to prevent sql injections on values and arguments
on all queries, for example, if we have:
```haskell
myEvilQuery :: (MonadIO m, MonadLogger m) => SqlWriteT m ()
myEvilQuery =
select (return $ val ("hi\'; DROP TABLE foo; select \'bye\'" :: String)) >>= liftIO . print
```
which generates this SQL(when using postgres):
```sql
SELECT 'hi''; DROP TABLE foo; select ''bye'''
```
And the printed value is `hi\'; DROP TABLE foo; select \'bye\'` and no table is dropped. This is good
and makes the use of strings values safe. Unfortunately this is not the case when using unsafe functions.
Let's see an example of defining a new evil `now` function:
```haskell
myEvilQuery :: (MonadIO m, MonadLogger m) => SqlWriteT m ()
myEvilQuery =
select (return nowWithInjection) >>= liftIO . print
where
nowWithInjection :: SqlExpr (Value UTCTime)
nowWithInjection = unsafeSqlFunction "0; DROP TABLE bar; select now" ([] :: [SqlExpr (Value Int)])
```
which generates this SQL:
```sql
SELECT 0; DROP TABLE bar; select now()
```
If we were to run the above code we would see the postgres time printed but the table `bar`
will be erased with no indication whatsoever. Another example of this behavior is seen when using
`unsafeSqlValue`:
```haskell
myEvilQuery :: (MonadIO m, MonadLogger m) => SqlWriteT m ()
myEvilQuery =
select (return $ dayPart dateWithInjection) >>= liftIO . print
where
dayPart :: SqlExpr (Value UTCTime) -> SqlExpr (Value Int)
dayPart s = unsafeSqlFunction "date_part" (unsafeSqlValue "\'day\'" :: SqlExpr (Value String) ,s)
dateWithInjection :: SqlExpr (Value UTCTime)
dateWithInjection = unsafeSqlValue "TIMESTAMP \'2001-02-16 20:38:40\');DROP TABLE bar; select (16"
```
which generates this SQL:
```sql
SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');DROP TABLE bar; select (16)
```
This will print 16 and also erase the `bar` table. The main take away of this examples is to
never use any user or third party input inside an unsafe function without first parsing it or
heavily sanitizing the input.
### Tests and Postgres