LINQ and Lambdas and Sprocs....Oh My!

There's a lot of great stuff in .NET 3.5 and several different ways to work with LINQ technologies such as LINQ to SQL.  I'm currently putting together some demonstration code for a talk I'll be giving at DevConnections in Orlando and showing how LINQ, Lambdas and LINQ with stored procedures can be used to do the same thing so that people get a feel for each technique.  For shorter queries I generally prefer lambdas since it's more object-oriented feeling compared to LINQ (to me anyway).  For more complex queries LINQ is much easier though.  Overall, I still prefer stored procedures since you have much more control over security that way and can maintain queries without resorting to C#/VB.NET code changes in some cases.  Plus, LINQ makes it really easy to pass parameters to stored procedures without having to create SqlParameter objects (something I've always despised).

Although I've found that I like lambdas a lot for more simple queries, I was working on some lambda code yesterday that was just plain out of control and much more complex when compared to using LINQ or LINQ against a sproc.  Here's an example of the overall query I was after which has several inner joins.  This particular query was automatically generated using LINQ code and I logged the output and converted it to a stored procedure named ap_GetOrderDetailsByOrderID.  It's structured a little differently than I would typically write, but accomplishes the same end goal.

CREATE PROCEDURE dbo.ap_GetOrderDetailsByOrderID
    (
        @OrderID int
    )
AS
    BEGIN
        SELECT [t5].[CompanyName] AS [ShipperName], 
        [t5].[ProductName] AS [Product], 
        [t5].[value] AS [Total], 
        CONVERT(Int,[t5].[Quantity]) AS [Quantity], 
        [t5].[UnitPrice], 
        [t5].[CompanyName2] AS [SupplierName] 
        FROM ( 
            SELECT [t0].[OrderID], 
                    [t1].[CompanyName], 
                    [t2].[UnitPrice], 
                    [t2].[Quantity], 
                    [t3].[ProductName], 
                    [t4].[CompanyName] AS [CompanyName2], 
                    (CONVERT(Decimal(29,4),[t2].[Quantity])) * [t2].[UnitPrice] AS [value] 
            FROM [dbo].[Orders] AS [t0] 
            INNER JOIN [dbo].[Shippers] AS [t1] ON [t0].[ShipVia] = ([t1].[ShipperID]) 
            INNER JOIN [dbo].[Order Details] AS [t2] ON [t0].[OrderID] = [t2].[OrderID] 
            INNER JOIN [dbo].[Products] AS [t3] ON [t2].[ProductID] = [t3].[ProductID] 
            INNER JOIN [dbo].[Suppliers] AS [t4] ON [t3].[SupplierID] = ([t4].[SupplierID]) ) 
        AS [t5] WHERE [t5].[OrderID] = @OrderID 

    END

The examples that follow go against the LINQ to SQL objects shown next that I created in Visual Studio 2008 using the LINQ to SQL Designer.  All of the objects came from the Northwind database except the custom OrderDescription object.

image

Using LINQ

LINQ can be used to automatically generate the query shown above by doing the following:

public override IEnumerable<OrderDescription> GetOrderDetails(int orderID)
{
    NorthwindDataContext db = this.DataContext;
    IEnumerable<OrderDescription> orderDetails =
        from o in db.Orders
        where o.OrderID == orderID
        join s in db.Shippers on o.ShipVia equals s.ShipperID
        join od in db.OrderDetails on o.OrderID equals od.OrderID
        join p in db.Products on od.ProductID equals p.ProductID
        join supplier in db.Suppliers on p.SupplierID equals supplier.SupplierID
        let total = od.Quantity * od.UnitPrice
        select new OrderDescription {Product = p.ProductName, Quantity = od.Quantity, 
                     ShipperName = s.CompanyName, Total = total, UnitPrice=od.UnitPrice,
                     SupplierName = supplier.CompanyName};
    return orderDetails;

}

This code joins 5 tables to grab order details and adds the target fields to the custom OrderDescription object.  By using this code the SQL is created on the fly from LINQ expression trees and sent to the database so any changes to the query require changes to the code of course.  For those that don't like working with stored procedures this certainly is the next best thing.

A better way of doing this that leverages relationships between objects defined in the LINQ to SQL data model is shown next (thanks to Christian Nagel):

IEnumerable<OrderDescription> orderDetails =
  from o in db.Orders
  where o.OrderID == orderID
  from od in o.OrderDetails
  let total = od.Quantity * od.UnitPrice
  select new OrderDescription
  {
      Product = od.Product.ProductName,
      Quantity = od.Quantity,
      ShipperName = o.Shipper.CompanyName,
      Total = total,
      UnitPrice = od.UnitPrice,
      SupplierName = od.Product.Supplier.CompanyName
  };
return orderDetails;


Using Lambdas

I mentioned earlier that I'm a big fan of lambdas when a particular query is reasonable.  However, they can get out of control.  The fairly straightforward LINQ query shown above gets pretty nasty when switching to lambdas since the joins require identifying the primary, foreign keys and fields to select.  This is lambda overkill....there are too many => characters in there for me, but it matches up with the LINQ query shown above pretty well.

public override IEnumerable<OrderDescription> GetOrderDetails(int orderID)
{
    NorthwindDataContext db = this.DataContext;
      IEnumerable<OrderDescription> orderDetails =
        db.Orders.Where(order => order.OrderID == orderID).
        Join(db.Shippers, o => o.ShipVia, s => s.ShipperID, 
          (o, s) => new { o.OrderID, ShipCompanyName = s.CompanyName }).
        Join(db.OrderDetails, o => o.OrderID, od => od.OrderID, 
          (o, od) => new {o.ShipCompanyName, od.ProductID, od.Quantity, od.UnitPrice }).
        Join(db.Products, od => od.ProductID, p => p.ProductID, 
          (OrderDetails, p) => new { OrderDetails, p.ProductName, p.SupplierID }).
        Join(db.Suppliers, p => p.SupplierID, s => s.SupplierID, 
          (OrderData, s) => new { OrderData, SupplierName = s.CompanyName}).
        Select(o => new OrderDescription
        {
            Product = o.OrderData.ProductName,
            Quantity = o.OrderData.OrderDetails.Quantity,
            ShipperName = o.OrderData.OrderDetails.ShipCompanyName,
            Total = o.OrderData.OrderDetails.Quantity * o.OrderData.OrderDetails.UnitPrice,
            UnitPrice = o.OrderData.OrderDetails.UnitPrice,
            SupplierName = o.SupplierName
        });
    return orderDetails;
}

By leveraging relationships in the object model generated by the LINQ to SQL Designer you can simplify this query a lot.  Here's an example of doing that (thanks to Dug for commenting and posting the refactored version):

public override IEnumerable<OrderDescription> GetOrderDetails(int orderID)
{
       NorthwindDataContext db = this.DataContext;

       IEnumerable<OrderDescription> orders =
         db.Orders.Where(order => order.OrderID == orderID).
         Join(db.OrderDetails, o => o.OrderID, od => od.OrderID,
         (o, od) => new { ShipCompanyName = o.Shipper.CompanyName, 
                          od.ProductID, 
                          ProductName = od.Product.ProductName, 
                          Quantity = od.Quantity, 
                          UnitPrice = od.UnitPrice, 
                          SupplierName = od.Product.Supplier.CompanyName }).

                         Select(o => new OrderDescription
                         {
                             Product = o.ProductName,
                             Quantity = o.Quantity,
                             ShipperName = o.ShipCompanyName,
                             Total = o.Quantity * o.UnitPrice,
                             UnitPrice = o.UnitPrice,
                             SupplierName = o.SupplierName
                         });
       return orders;
}


Using LINQ with Stored Procedures

This is my favorite technique.  While LINQ makes it easy to query against a database without embedding inline SQL into C# or VB.NET, using pure LINQ code still doesn't provide the same level of security that stored procedures can provide, requires that SQL be generated dynamically from LINQ expression trees and can complicate application maintenance down the road in my opinion.  To call the stored procedure shown at the beginning of this post using LINQ to SQL techniques you can use the following code once the stored procedure has been drag and dropped onto the LINQ to SQL designer surface.  This code is simple and easy to maintain.  Plus, I can filter the results even more by using LINQ or by adding lambdas onto the ap_GetOrderDetailsByOrderID() method if needed.

public override IEnumerable<OrderDescription> GetOrderDetails(int orderID)
{
    IEnumerable<OrderDescription> orderDetails = DataContext.ap_GetOrderDetailsByOrderID(orderID);
    return orderDetails;
}

Ultimately it all comes down to personal preference.  Having worked through many LINQ, lambda and stored procedure queries I'll be sticking with LINQ to SQL with sprocs since the code is squeaky clean.  I have a few friends who prefer using inline LINQ as shown in the first example and we've argued the pros and cons of each technique back and forth.  The beauty of it all is that we get to use what we want and have multiple options to choose from!

I'll post the demo code I've been working on soon so those who are interested in getting into LINQ, lambdas and LINQ with sprocs can see how each technique can be used in an n-tier application architecture.

 

comments powered by Disqus

7 Comments

  • Yet another alternative to assist would be to use a view to simplify the code.
    Not to be a smarty pants or anything... This would be a good scenario to ease the pain and complexity. I would be curious to see a benchmark between the three, proc and view would probably be a minimal.

    Nice example of push the technology in a thick instance!

  • Great article - would like to see much more Linq to SQL using stored procs - the inline sql gives me an uneasy feeling when using it.

  • Thanks for the comment Ryan. Views would definitely be a good idea in this example especially for people that don't necessarily want stored procedures but yet want simplified LINQ or lambda queries. I haven't taken the time to benchmark the three options...that would definitely be interesting though.

  • Gregor,

    Glad the post was beneficial. I agree with the "uneasy feeling" you mentioned. We've been told for years to use stored procedures and avoid inline SQL but now LINQ tends to put things into more of a gray area. But, people can choose what they like most which makes it cool.

  • Damien,
    In cases where a developer is&nbsp;contracting and shipping DB changes in a migration script then I would agree with you (having worked in that environment...which can definitely be painful at times) as long as the DB is SQL 2000/2005 of course.&nbsp; In other cases where developers work directly at a company and have access to either the database or DBAs then I'd still prefer stored procedures there.&nbsp;
    The nice thing is that it really doesn't matter what I think since people can choose what's best for their situation and LINQ gives them a lot of flexibility in that choice.

  • Interesting post - Could you explain why are you using such complicated linq/lambda expressions. Are you concerned about the sql that is being produced?

    I tried the following lambda expression and got the same result and a very similar sql
    IEnumerable orders =
    db.Orders.Where(order => order.OrderID == orderID).
    Join(db.OrderDetails, o => o.OrderID, od => od.OrderID,
    (o, od) => new { ShipCompanyName = o.Shipper.CompanyName, od.ProductID, ProductName = od.Product.ProductName, Quantity = od.Quantity, UnitPrice = od.UnitPrice, SupplierName = od.Product.Supplier.CompanyName }).
    Select(o => new OrderDescription
    {
    Product = o.ProductName,
    Quantity = o.Quantity,
    ShipperName = o.ShipCompanyName,
    Total = o.Quantity * o.UnitPrice,
    UnitPrice = o.UnitPrice,
    SupplierName = o.SupplierName
    });

    I also tried:
    List orders = new List();
    Order order = db.Orders.Where(o => o.OrderID == orderID).Single();

    foreach (OrderDetail od in order.OrderDetails)
    {
    orders.Add(new OrderDescription
    {
    Product = od.Product.ProductName,
    Quantity = od.Quantity,
    ShipperName = order.Shipper.CompanyName,
    SupplierName = od.Product.Supplier.CompanyName,
    Total = od.Quantity * od.UnitPrice,
    UnitPrice = od.UnitPrice
    });
    }

    Which resulted in two additional sql query for each order detail to look up the product and the supplier. This can be prevented by adding the following immediate loading directives to the method:

    System.Data.Linq.DataLoadOptions loadoptions = new DataLoadOptions();
    loadoptions.LoadWith(o => o.OrderDetails);
    loadoptions.LoadWith(o => o.Shipper);
    loadoptions.LoadWith(od => od.Product);
    loadoptions.LoadWith(p => p.Supplier);

    db.LoadOptions = loadoptions;

    This results in a some very ugly sql which seems to be reasonable similar to the original query.

    I did not check any of the execution plans when comparing the sql that was produced.

  • Dug,

    Thanks for commenting. Yeah....the Lambda query is overly complex. I was trying to mirror the LINQ query as closely as possible just to show what it would look like. I should probably post what you list above as well since in reality people will be leveraging the data relationships in the object model.

Comments have been disabled for this content.