Skip to content

Commit

Permalink
Document new FromSql{Raw,Interpolated} methods
Browse files Browse the repository at this point in the history
Closes #1667
  • Loading branch information
roji committed Sep 20, 2019
1 parent dbd8246 commit 60941a9
Show file tree
Hide file tree
Showing 2 changed files with 55 additions and 34 deletions.
75 changes: 48 additions & 27 deletions entity-framework/core/querying/raw-sql.md
Original file line number Diff line number Diff line change
Expand Up @@ -7,19 +7,19 @@ uid: core/querying/raw-sql
---
# Raw SQL Queries

Entity Framework Core allows you to drop down to raw SQL queries when working with a relational database. This can be useful if the query you want to perform can't be expressed using LINQ, or if using a LINQ query is resulting in inefficient SQL queries. Raw SQL queries can return entity types or, starting with EF Core 2.1, [keyless entity types](xref:core/modeling/keyless-entity-types) that are part of your model.
Entity Framework Core allows you to drop down to raw SQL queries when working with a relational database. This can be useful if the query you want to perform can't be expressed using LINQ, or if using a LINQ query is resulting in an inefficient SQL query. Raw SQL queries can return regular entity types or [keyless entity types](xref:core/modeling/keyless-entity-types) that are part of your model.

> [!TIP]
> You can view this article's [sample](https://github.com/aspnet/EntityFramework.Docs/tree/master/samples/core/Querying) on GitHub.
> You can view this article's [sample](https://github.com/aspnet/EntityFramework.Docs/tree/master/samples/core/Querying/Querying/RawSQL/Sample.cs) on GitHub.
## Basic raw SQL queries

You can use the *FromSql* extension method to begin a LINQ query based on a raw SQL query.
You can use the `FromSqlRaw` extension method to begin a LINQ query based on a raw SQL query.

<!-- [!code-csharp[Main](samples/core/Querying/RawSQL/Sample.cs)] -->
``` csharp
var blogs = context.Blogs
.FromSql("SELECT * FROM dbo.Blogs")
.FromSqlRaw("SELECT * FROM dbo.Blogs")
.ToList();
```

Expand All @@ -28,44 +28,53 @@ Raw SQL queries can be used to execute a stored procedure.
<!-- [!code-csharp[Main](samples/core/Querying/RawSQL/Sample.cs)] -->
``` csharp
var blogs = context.Blogs
.FromSql("EXECUTE dbo.GetMostPopularBlogs")
.FromSqlRaw("EXECUTE dbo.GetMostPopularBlogs")
.ToList();
```

## Passing parameters

As with any API that accepts SQL, it is important to parameterize any user input to protect against a SQL injection attack. You can include parameter placeholders in the SQL query string and then supply parameter values as additional arguments. Any parameter values you supply will automatically be converted to a `DbParameter`.
> [!WARNING]
> **Always use parameterization for raw SQL queries**
>
> When introducing any user-provided values into a raw SQL query, care must be taken to avoid SQL injection attacks. In addition to validating that such values don't contain invalid characters, always use parameterization which sends the values separate from the SQL text.
>
> In particular, never pass a concatenated or interpolated string (`$""`) with unvalidated user-provided values into `FromSqlRaw` or `ExecuteSqlRaw`. The `FromSqlInterpolated` and `ExecuteSqlInterpolated` methods allow using string interpolation syntax in a way that protects against SQL injection attacks.
The following example passes a single parameter to a stored procedure. While this may look like `String.Format` syntax, the supplied value is wrapped in a parameter and the generated parameter name inserted where the `{0}` placeholder was specified.
The following example passes a single parameter to a stored procedure by including a parameter placeholder in the SQL query string and providing an additional argument. While this may look like `String.Format` syntax, the supplied value is wrapped in a `DbParameter` and the generated parameter name inserted where the `{0}` placeholder was specified.

<!-- [!code-csharp[Main](samples/core/Querying/RawSQL/Sample.cs)] -->
``` csharp
var user = "johndoe";

var blogs = context.Blogs
.FromSql("EXECUTE dbo.GetMostPopularBlogsForUser {0}", user)
.FromSqlRaw("EXECUTE dbo.GetMostPopularBlogsForUser {0}", user)
.ToList();
```

This is the same query but using string interpolation syntax, which is supported in EF Core 2.0 and above:
As an alternative to `FromSqlRaw`, you can use `FromSqlInterpolated` which allows the safe use of string interpolation. As with the previous example, the value is converted to a `DbParameter` and is therefore not vulnerable to SQL injection:

> [!NOTE]
> Prior to version 3.0, `FromSqlRaw` and `FromSqlInterpolated` were two overloads named `FromSql`. See the [previous versions section](#previous-versions) for more details.

<!-- [!code-csharp[Main](samples/core/Querying/RawSQL/Sample.cs)] -->
``` csharp
var user = "johndoe";

var blogs = context.Blogs
.FromSql($"EXECUTE dbo.GetMostPopularBlogsForUser {user}")
.FromSqlInterpolated($"EXECUTE dbo.GetMostPopularBlogsForUser {user}")
.ToList();
```

You can also construct a DbParameter and supply it as a parameter value:
You can also construct a DbParameter and supply it as a parameter value. Since a regular SQL parameter placeholder is used, rather than a string placeholder, `FromSqlRaw` can be safely used:

<!-- [!code-csharp[Main](samples/core/Querying/RawSQL/Sample.cs)] -->
``` csharp
var user = new SqlParameter("user", "johndoe");

var blogs = context.Blogs
   .FromSql("EXECUTE dbo.GetMostPopularBlogsForUser @user", user)
   .FromSqlRaw("EXECUTE dbo.GetMostPopularBlogsForUser @user", user)
.ToList();
```

Expand All @@ -76,7 +85,7 @@ This allows you to use named parameters in the SQL query string, which is useful
var user = new SqlParameter("user", "johndoe");

var blogs = context.Blogs
   .FromSql("EXECUTE dbo.GetMostPopularBlogs @filterByUser=@user", user)
   .FromSqlRaw("EXECUTE dbo.GetMostPopularBlogs @filterByUser=@user", user)
.ToList();
```

Expand All @@ -91,60 +100,72 @@ The following example uses a raw SQL query that selects from a Table-Valued Func
var searchTerm = ".NET";

var blogs = context.Blogs
.FromSql($"SELECT * FROM dbo.SearchBlogs({searchTerm})")
.FromSqlInterpolated($"SELECT * FROM dbo.SearchBlogs({searchTerm})")
.Where(b => b.Rating > 3)
.OrderByDescending(b => b.Rating)
.ToList();
```

This will produce the following SQL query:

``` sql
SELECT [b].[Id], [b].[Name], [b].[Rating]
FROM (
SELECT * FROM dbo.SearchBlogs(@p0)
) AS b
WHERE b."Rating" > 3
ORDER BY b."Rating" DESC
```

## Change Tracking

Queries that use the `FromSql()` follow the exact same change tracking rules as any other LINQ query in EF Core. For example, if the query projects entity types, the results will be tracked by default.
Queries that use the `FromSql` methods follow the exact same change tracking rules as any other LINQ query in EF Core. For example, if the query projects entity types, the results will be tracked by default.

The following example uses a raw SQL query that selects from a Table-Valued Function (TVF), then disables change tracking with the call to .AsNoTracking():
The following example uses a raw SQL query that selects from a Table-Valued Function (TVF), then disables change tracking with the call to `AsNoTracking`:

<!-- [!code-csharp[Main](samples/core/Querying/RawSQL/Sample.cs)] -->
``` csharp
var searchTerm = ".NET";

var blogs = context.Query<SearchBlogsDto>()
.FromSql($"SELECT * FROM dbo.SearchBlogs({searchTerm})")
.FromSqlInterpolated($"SELECT * FROM dbo.SearchBlogs({searchTerm})")
.AsNoTracking()
.ToList();
```

## Including related data

The `Include()` method can be used to include related data, just like with any other LINQ query:
The `Include` method can be used to include related data, just like with any other LINQ query:

<!-- [!code-csharp[Main](samples/core/Querying/RawSQL/Sample.cs)] -->
``` csharp
var searchTerm = ".NET";

var blogs = context.Blogs
   .FromSql($"SELECT * FROM dbo.SearchBlogs({searchTerm})")
   .FromSqlInterpolated($"SELECT * FROM dbo.SearchBlogs({searchTerm})")
   .Include(b => b.Posts)
.ToList();
```

Note that this requires your raw SQL query to be composable; it will notably not work with stored procedure calls. See notes on composability under [Limitations](#limitations)).

## Limitations

There are a few limitations to be aware of when using raw SQL queries:

* The SQL query must return data for all properties of the entity or query type.
* The SQL query must return data for all properties of the entity type.

* The column names in the result set must match the column names that properties are mapped to. Note this is different from EF6 where property/column mapping was ignored for raw SQL queries and result set column names had to match the property names.

* The SQL query cannot contain related data. However, in many cases you can compose on top of the query using the `Include` operator to return related data (see [Including related data](#including-related-data)).

* `SELECT` statements passed to this method should generally be composable: If EF Core needs to evaluate additional query operators on the server (for example, to translate LINQ operators applied after `FromSql`), the supplied SQL will be treated as a subquery. This means that the SQL passed should not contain any characters or options that are not valid on a subquery, such as:
* a trailing semicolon
* `SELECT` statements passed to this method should generally be composable: If EF Core needs to evaluate additional query operators on the server (for example, to translate LINQ operators applied after `FromSql` methods), the supplied SQL will be treated as a subquery. This means that the SQL passed should not contain any characters or options that are not valid on a subquery, such as:
* A trailing semicolon
* On SQL Server, a trailing query-level hint (for example, `OPTION (HASH JOIN)`)
* On SQL Server, an `ORDER BY` clause that is not accompanied of `OFFSET 0` OR `TOP 100 PERCENT` in the `SELECT` clause

* SQL statements other than `SELECT` are recognized automatically as non-composable. As a consequence, the full results of stored procedures are always returned to the client and any LINQ operators applied after `FromSql` are evaluated in-memory.
* Note that SQL Server does not allow composing over stored procedure calls, so any attempt to apply additional query operators to such a call will result in invalid SQL. Query operators may be introduced after `AsEnumerable()` for client evaluation.

# Previous versions

> [!WARNING]
> **Always use parameterization for raw SQL queries:** In addition to validating user input, always use parameterization for any values used in a raw SQL query/command. APIs that accept a raw SQL string such as `FromSql` and `ExecuteSqlCommand` allow values to be easily passed as parameters. Overloads of `FromSql` and `ExecuteSqlCommand` that accept FormattableString also allow using string interpolation syntax in a way that helps protect against SQL injection attacks.
>
> If you are using string concatenation or interpolation to dynamically build any part of the query string, or passing user input to statements or stored procedures that can execute those inputs as dynamic SQL, then you are responsible for validating any input to protect against SQL injection attacks.
EF Core version 2.2 and earlier had two overloads named `FromSql` which behaved in the same way as the newer `FromSqlRaw` and `FromSqlInterpolated`. This made it very easy to accidentally call the raw string method when the intent was to call the interpolated string method, and the other way around. This could result in queries not being parameterized when they should have been.
14 changes: 7 additions & 7 deletions samples/core/Querying/RawSQL/Sample.cs
Original file line number Diff line number Diff line change
Expand Up @@ -11,14 +11,14 @@ public static void Run()
using (var context = new BloggingContext())
{
var blogs = context.Blogs
.FromSql("SELECT * FROM dbo.Blogs")
.FromSqlRaw("SELECT * FROM dbo.Blogs")
.ToList();
}

using (var context = new BloggingContext())
{
var blogs = context.Blogs
.FromSql("EXECUTE dbo.GetMostPopularBlogs")
.FromSqlRaw("EXECUTE dbo.GetMostPopularBlogs")
.ToList();
}

Expand All @@ -27,7 +27,7 @@ public static void Run()
var user = "johndoe";

var blogs = context.Blogs
.FromSql("EXECUTE dbo.GetMostPopularBlogsForUser {0}", user)
.FromSqlRaw("EXECUTE dbo.GetMostPopularBlogsForUser {0}", user)
.ToList();
}

Expand All @@ -36,7 +36,7 @@ public static void Run()
var user = "johndoe";

var blogs = context.Blogs
.FromSql($"EXECUTE dbo.GetMostPopularBlogsForUser {user}")
.FromSqlInterpolated($"EXECUTE dbo.GetMostPopularBlogsForUser {user}")
.ToList();
}

Expand All @@ -45,7 +45,7 @@ public static void Run()
var user = new SqlParameter("user", "johndoe");

var blogs = context.Blogs
.FromSql("EXECUTE dbo.GetMostPopularBlogsForUser @user", user)
.FromSqlRaw("EXECUTE dbo.GetMostPopularBlogsForUser @user", user)
.ToList();
}

Expand All @@ -54,7 +54,7 @@ public static void Run()
var searchTerm = ".NET";

var blogs = context.Blogs
.FromSql($"SELECT * FROM dbo.SearchBlogs({searchTerm})")
.FromSqlInterpolated($"SELECT * FROM dbo.SearchBlogs({searchTerm})")
.Where(b => b.Rating > 3)
.OrderByDescending(b => b.Rating)
.ToList();
Expand All @@ -65,7 +65,7 @@ public static void Run()
var searchTerm = ".NET";

var blogs = context.Blogs
.FromSql($"SELECT * FROM dbo.SearchBlogs({searchTerm})")
.FromSqlInterpolated($"SELECT * FROM dbo.SearchBlogs({searchTerm})")
.Include(b => b.Posts)
.ToList();
}
Expand Down

0 comments on commit 60941a9

Please sign in to comment.