Maintaining deep hierarchical data in SQL Server

5. April 2015 12:19 by Parakh in SQL Server  //  Tags: , ,   //   Comments

Key Takeaway:

Every development project in some way has to deal with hierarchical data. That comes in the form of catalogs, cascading choices etc. In my previous article I demonstrated a way to maintain simple 2 level hierarchical data. In this article I will demonstrated the most optimal way of storing deep hierarchical data, that cannot be efficiently maintained using key-value pair setup. The way to do this is by using a dedicated data type in SQL Server – HierarchyId.

The article will not go deep into explaining about hierarchyid or the methods that accompany it, but rather will show how to use the data type in real world scenarios.

Read On:

When you have to store a complex hierarchy, traversing and manipulating that hierarchy becomes a tedious task. Nested hierarchy that goes beyond a flat 2 tier level is better managed with the help of a dedicated data type in SQL Server – HierarchyId.

HierarchyId is an in-built data-type in SQL Server and is based on CLR representation of binary data. It essentially stores an ordered path in an efficient manner. Because it is a CLR based data-types, there are methods that are available that can be leveraged in SQL queries to work with the data type. Although it is based on CLR, you do not have to take any additional steps in SQL Server to enable the use of the data type. It was first introduced in SQL Server 2008.

I will use some of the methods in this article to show you how to maintain a simple hierarchy. I will be re-using the example from my previous post and will try to store a hierarchy of different types of vehicles depending upon the environment in which they can be used.

Hierarchy of vehicles

 

 

 

 

 

 

 

 

Figure 1 Hierarchy of vehicles

In order to accommodate such a hierarchy, let’s create a data model. The data model in our case will only consists of a single table. This table can then be connected to the rest of the tables in the main data model with the help of primary-foreign key relationship.

image

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

Figure 2 Table that will capture the hierarchy. Bold entries are required.

HierarchyData Table:

Column Name

Data type

Description

Id

Int

The auto incrementing integer type primary key.

Hierarchy

Hierarchyid

Binary representation of ordered path using data type hierarchyid.

HierarchyPath

Computed

A computed column to show path of a node in the hierarchy as a string for our easy comprehension.

HierarchyLevel

Computed

A computed column to show level of a node in the hierarchy as am integer value for our easy comprehension.

Entry

Navarchar(100)

Entry denoting either a parent or child.

Description

Nvarchar(1000)

Description about entry.

ShortName

Nvarchar(20)

Short string about node which will be leveraged in where clause in SQL queries.

IsActive

Bit

Bit field denoting if an entry is active or not.

CreatedBy

Nvarchar(100)

Entry to denote who actually created the entry.

CreatedDate

Datetime

Entry denoting the date and time when the entry was created.

ModifiedBy

Nvarchar(100)

Entry to denote who modified the entry.

ModifiedDate

Datetime

Entry denoting the date and time when the entry was modified.

Contrast this with the data model as presented in the previous article. You will notice that in this case we are only using a single table to store both the parent and the child entries.

As is done in the previous article, for our ease of querying, we will maintain a column called “ShortName” that will be used in where clause in all the queries. This makes the queries independent of the primary key column, in which the value may change as we move the data from one environment to another.

Now here’s the SQL that you can use to create the table and fill it up with data.

-- Creation of table
Create Table dbo.HierarchyData
(
    Id int identity(1,1) primary key,
    Hierarchy hierarchyid not null,
    HierarchyPath as Hierarchy.ToString(),
    HierarychyLevel as Hierarchy.GetLevel(),
    Entry nvarchar(100) not null,
    Description nvarchar(1000),
    ShortName nvarchar(20) not null,
    IsActive bit not null,
    CreatedBy nvarchar(100) not null,
    CreatedDate datetime not null,
    ModifiedBy nvarchar(100) null,
    ModifiedDate datetime null
);
 
-- Insertion of data
Declare 
@Root hierarchyid,
@Parent hierarchyid,
@SiblingOnRight hierarchyid,
@SiblingOnLeft hierarchyid,
@HierarchyValue hierarchyid;
 
Set @Root = hierarchyid::GetRoot();
Insert into dbo.HierarchyData Values
(@Root,'Root Level','Root Level','ROOT', 1, 'Parakh Singhal',GetUtcDate(),null,null);
 
Select @HierarchyValue = @Root.GetDescendant(null,null);
Insert into dbo.HierarchyData values
(@HierarchyValue,'Ground Vehicles','Ground Vehicles','GRND_VEH',1,'Parakh Singhal', GetUtcDate(),null,null);
 
Select @SiblingOnLeft = Hierarchy from dbo.HierarchyData where ShortName = 'GRND_VEH';
Set @HierarchyValue = @Root.GetDescendant(@SiblingOnLeft,null);
Insert into dbo.HierarchyData values
(@HierarchyValue,'Air Vehicles','Air Vehicles','AIR_VEH',1,'Parakh Singhal', GetUtcDate(),null,null);
 
Select @SiblingOnLeft = Hierarchy from dbo.HierarchyData where ShortName = 'AIR_VEH';
Set @HierarchyValue = @Root.GetDescendant(@SiblingOnLeft,null);
Insert into dbo.HierarchyData values
(@HierarchyValue,'Water Vehicles','Water Vehicles','WATER_VEH',1,'Parakh Singhal',GetUtcDate(),null,null);
 
Select @HierarchyValue = Hierarchy.GetDescendant(null,null) from dbo.HierarchyData where ShortName = 'GRND_VEH';
Insert into dbo.HierarchyData values
(@HierarchyValue,'Trucks','Trucks','GRND_VEH_TRUCKS',1,'Parakh Singhal',GetUtcDate(),null,null);
 
Select @Parent = Hierarchy from dbo.HierarchyData where ShortName = 'GRND_VEH';
Select @SiblingOnLeft = Hierarchy from dbo.HierarchyData where ShortName = 'GRND_VEH_TRUCKS';
Set @HierarchyValue = @Parent.GetDescendant(@SiblingOnLeft,null);
Insert into dbo.HierarchyData values
(@HierarchyValue,'Cars','Cars','GRND_VEH_CARS',1,'Parakh Singhal',GetUtcDate(),null,null);
 
Select @Parent = Hierarchy.GetDescendant(null,null) from dbo.HierarchyData where ShortName = 'AIR_VEH';
Set @HierarchyValue = @Parent;
Insert into dbo.HierarchyData values
(@HierarchyValue,'Hot Air Baloon','Hot Air Baloon','AIR_VEH_BALOON',1,'Parakh Singhal',GetUtcDate(),null,null);
 
Select @Parent = Hierarchy from dbo.HierarchyData where ShortName = 'AIR_VEH';
Select @SiblingOnLeft = Hierarchy from dbo.HierarchyData where ShortName = 'AIR_VEH_BALOON';
Set @HierarchyValue = @Parent.GetDescendant(@SiblingOnLeft,null);
Insert into dbo.HierarchyData values
(@HierarchyValue,'Airplane','Airplane','AIR_VEH_AIRPLANE',1,'Parakh Singhal',GetUtcDate(),null,null);
 
Select @Parent = Hierarchy from dbo.HierarchyData where ShortName = 'WATER_VEH';
Set @HierarchyValue = @Parent.GetDescendant(null,null);
Insert into dbo.HierarchyData values
(@HierarchyValue,'Ship','Ship','WATER_VEH_SHIP',1,'Parakh Singhal',GetUtcDate(),null,null);
 
Select @Parent = Hierarchy from dbo.HierarchyData where ShortName = 'WATER_VEH';
Select @SiblingOnLeft = Hierarchy from dbo.HierarchyData where ShortName = 'WATER_VEH_SHIP';
Set @HierarchyValue = @Parent.GetDescendant(@SiblingOnLeft,null);
Insert into dbo.HierarchyData values
(@HierarchyValue,'Submarine','Submarine','WATER_VEH_SUBMARINE',1,'Parakh Singhal',GetUtcDate(),null,null);

And here’s the SQL that you can use to query some of the most common scenarios like:

1. Traversing down the hierarchy from a parent node,

2. Traversing up the hierarchy from a child node,

3. Finding the level of a node in the hierarchy,

4. Determining is a node is the child of a node,

5. Finding the ancestor of a child node.

Declare
@Root hierarchyid,
@Parent hierarchyid,
@Child hierarchyid,
@Node hierarchyid;
 
-- Selecting the entire table contents.
Select * from dbo.HierarchyData;
 
-- Finding the root element.
Set @Root = hierarchyid::GetRoot();
Select * from dbo.HierarchyData where Hierarchy = @Root;
 
-- Climbing down a hierarchy
-- Selecting a hierarhcy of nodes belonging to a parent.
Select @Parent = Hierarchy from dbo.HierarchyData where ShortName = 'GRND_VEH';
 
Select * from dbo.HierarchyData 
where Hierarchy.IsDescendantOf(@Parent) = 1;
 
-- Climbing up the hierarchy
-- Selecting all the parents of a node
Select @Node = Hierarchy from dbo.HierarchyData where ShortName = 'WATER_VEH_SUBMARINE';
 
Select * from dbo.HierarchyData 
where @Node.IsDescendantOf(Hierarchy) = 1;
 
-- Getting level of a node in the hierarchy.
Select Hierarchy.GetLevel() as HierarchyLevel from dbo.HierarchyData where ShortName = 'AIR_VEH_AIRPLANE';
 
-- Determining if a node is a child of a node.
Select @Parent = Hierarchy from dbo.HierarchyData where ShortName = 'GRND_VEH';
Select @Child = Hierarchy from dbo.HierarchyData where ShortName = 'GRND_VEH_TRUCKS'
 
Select @Child.IsDescendantOf(@Parent) as Result;
 
-- Determining an ancestor
-- The query selects the immediate ancestor.
Select @Node = Hierarchy from dbo.HierarchyData where ShortName = 'GRND_VEH_CARS';
Select * from dbo.HierarchyData where Hierarchy = @Node.GetAncestor(1);

Brief overview of some of the methods used in aforementioned sql queries:

1. GetRoot(): GetRoot methods when used on a hierarchyid type value will return the hierarchyid type value of the absolute root of the hierarchy.

2. GetDescendant(): Methods when used on a hierarchyid type value will return a hierarchyid type value. You can use this method to generate a new hierarchyid value when inserting data, the way I have demonstrated.

Notice that in order to create nodes that are siblings, you need to specify a pre-existing sibling (See the creation of water and air vehicles that are siblings to ground vehicles). Depending upon where you want to place the sibling in the hierarchy, you might need to provide both the sibling on the left and right in the hierarchy. Since I want to treat both air and water vehicles, I only mentioned sibling on the left in the hierarchy. If you want to place another category, say, amphibious vehicles between water and ground vehicles, then you will have to mention ground vehicles as the sibling on the left and water vehicles as the sibling on the right.

3. IsDescendantOf(): Method takes in a hierarchy id as input and returns a Boolean, if that is true.

4. GetAncestor(): Method takes in an integer value and gives the parent of the child node, depending on the integer value provided. The integer depicts the level in the hierarchy.

As you can see in the code above, maintaining a deep hierarchy with the help of hierarchyid is easy. It does not require cumbersome recursive Common Table Expressions and multiple tables to maintain, and yet offers more flexibility.

I have not gone deep into explaining about hierarchyid and the methods that accompany it. The main motive of this article is to demonstrate with the help of working code, how to maintain hierarchical data with the help of in-built mechanism in SQL Server.

References:

1. Model Your Data Hierarchies With SQL Server 2008

2. SQL Server 2008 - HierarchyID - Part I

3. Hierarchies with HierarchyID in SQL 2008

Simple way to maintain 2 level hierarchical data in SQL Server

23. March 2015 12:53 by Parakh in SQL Server  //  Tags: , ,   //   Comments

Key takeaway:

Often we are required to maintain simple 2 level hierarchical data in databases. Such data is generally used to power dropdowns, radio button groups, checkboxes etc. where user input is required. This data is generally persisted in relational databases in separate tables which connect to the tables of interest via one to many relationships.

This method suggests a key-value like system to maintain such data, thereby reducing the total number of tables and at the same time maintaining flexibility to extend your data-model.

Read on:

I have been working on projects and have implemented a simple way to maintain simple 2 level hierarchical data. A lot of them were focused on replacing a Content Management System that has been in use since the last decade with small dedicated systems that are flexible and correspond to the changing business landscape. One concept that we borrowed from the legacy system was the system to maintain data that drive business logic in an application using key-value like 2 level hierarchical data. Since a CMS can be used to manage a variety of data that the company making the CMS cannot know about in advance, the pattern is used in such systems.

At the heart of the concept are two tables – one to store parent data and the other table that houses child data. Hence key-value like one to many hierarchy.

Let’s take an example:

We will be modeling the kinds of transports that exist and the corresponding vehicles.

Consider the following data-model for such a system:

Data model

Description: The data-model of the setup of key-value tables. Bold entries are required fields.

Key Table:

Column Name

Data type

Description

KeyID

Int (Primary key)

The auto incrementing int type primary key.

Key

Nvarchar(100)

The entry that denotes the parent.

Description

Nvarchar(1000)

Description about the parent.

ShortName

Nvarchar(50) (Unique)

A short abbreviation for the parent entry. This will be used in where clause in sql queries instead of primary key, as there’s a possibility of primary key changing when data is moved from one environment to another (e.g. dev to test). The short name is going to remain constant and unique

IsActive

Bit

Denotes whether the entry is active or not.

CreatedBy

Nvarchar(100)

Entry to denote who actually created the entry.

CreatedDate

DateTime

Entry denoting the date and time when the entry was created.

ModifiedBy

Nvarchar(100)

Entry to denote who modified the entry.

ModifiedDate

DateTime

Entry denoting the date and time when the entry was modified.

Value Table:

Column Name

Data type

Description

ValueID

Int (Primary key)

The auto incrementing int type primary key.

KeyID

Int (Foreign key)

Reference to the primary key ValueListID in ValueList table.

Sequence

Int

The sequence denotes the order in which the child entries should appear in a select statement. This is helpful in defining an order in case of dropdowns.

Value

Nvarchar(100)

The entry that denotes the child of the parent entry in ValueList table.

Description

Nvarchar(1000)

Description about the child entry.

ShortName

Nvarchar(50) (Unique)

A short abbreviation for the child entry. This will be used in where clause in sql queries instead of primary key, as there’s a possibility of primary key changing when data is moved from one environment to another (e.g. dev to test). The short name is going to remain constant and unique

IsActive

Bit

Denotes whether the entry is active or not.

CreatedBy

Nvarchar(100)

Entry to denote who actually created the entry.

CreatedDate

DateTime

Entry denoting the date and time when the entry was created.

ModifiedBy

Nvarchar(100)

Entry to denote who modified the entry.

ModifiedDate

DateTime

Entry denoting the date and time when the entry was modified.

As you can see from the data model, the parent entries are kept in the Key table and the child entries are kept in the Value table. The two tables are related via one to many relationship. The role of the ShortName field in both the tables is to help in the creation of sql queries that include the where clause based on which selection can be done. Often data is moved from one environment to other, and in the process it may happen that the primary key may change. This is especially true of databases where uniqueidentifier data type keys are used as surrogate primary keys, like data models of content management systems.

Now let’s create these tables and fill them up with some data.

Create Table dbo.[Key]
(
    KeyID Int identity(1,1) Primary key,
    [Key]    Nvarchar(100),
    Description    Nvarchar(1000),
    ShortName    Nvarchar(50) Unique,
    IsActive    Bit,
    CreatedBy    Nvarchar(100),
    CreatedDate    DateTime,
    ModifiedBy    Nvarchar(100),
    ModifiedDate    DateTime
);
Go
 
Create Table dbo.Value
(
    ValueID    Int Identity(1,1) Primary key,
    KeyID    Int,
    Sequence    Int,
    Value    Nvarchar(100),
    Description    Nvarchar(1000),
    ShortName    Nvarchar(50) Unique,
    IsActive    Bit,
    CreatedBy    Nvarchar(100),
    CreatedDate    DateTime,
    ModifiedBy    Nvarchar(100),
    ModifiedDate    DateTime
);
Go
 
Alter Table dbo.Value
Add Constraint FK_Value_Key Foreign Key (KeyId)
References dbo.[Key](KeyId);
Go
 
Create NonClustered Index NCI_Value_KeyId on dbo.Value(KeyId);
Go
 
Create NonClustered Index NCI_Value_ShortName on dbo.Value(ShortName);
Go
 
Insert into dbo.[Key] Values
('Ground Vehicles','Vehicles available for use on ground','GRND_VEH',1,'Parakh Singhal',GetDate(),null,null),
('Sea Vehicles','Vehicles available for use in sea','SEA_VEH',1,'Parakh Singhal',GetDate(),null,null),
('Air Vehicles','Vehicles available for use in air','AIR_VEH',1,'Parakh Singhal',GetDate(),null,null);
 
Insert into dbo.Value Values
(1,0,'Car','Car','GRND_VEH_CAR',1,'Parakh Singhal',GetDate(),null,null),
(1,0,'Truck','Truck','GRND_VEH_TRK',1,'Parakh Singhal',GetDate(),null,null),
(2,0,'Submarine','Submarine','SEA_VEH_SBM',1,'Parakh Singhal',GetDate(),null,null),
(2,0,'Ship','Ship','SEA_VEH_SHP',1,'Parakh Singhal',GetDate(),null,null),
(3,0,'Air Plane','Air Plane','AIR_VEH_PLN',1,'Parakh Singhal',GetDate(),null,null),
(3,0,'Hot Air Baloon','Hot Air Baloon','AIR_VEH_BLN',1,'Parakh Singhal',GetDate(),null,null);

 

Now suppose we have to query the different types of vehicles that available for use on ground, then we can run the following query:

SELECT dbo.Value.ValueID
      ,dbo.Value.KeyID
      ,dbo.Value.Sequence
      ,dbo.Value.Value
      ,dbo.Value.Description
      ,dbo.Value.ShortName
      ,dbo.Value.IsActive
      ,dbo.Value.CreatedBy
      ,dbo.Value.CreatedDate
      ,dbo.Value.ModifiedBy
      ,dbo.Value.ModifiedDate
  FROM dbo.Value Inner Join dbo.[Key]
on dbo.Value.KeyID = dbo.[Key].KeyID
where dbo.[Key].ShortName = 'GRND_VEH'

Summary:

Key-Value tables form a very concise way to store 2 level hierarchical data. The idea is primarily applied in case of content management systems where the product company cannot know in advance as what all categories will be created in the system. Using this concept you can get rid of a lot of tables that are just used to store ‘choice’ or ‘category’ data.

Inserting Multiple Rows in SQL Server via Table Valued Parameters

26. February 2014 11:40 by Parakh in ASP.NET, SQL Server  //  Tags: , ,   //   Comments
This post covers how can we insert multiple rows worth of data via table valued parameters in SQL Server database.

Key take away:

In my last posts, I have described ways to insert multiple rows worth of data in a SQL Server database via a Comma Separated List and XML. In this post I will describe how to insert multiple rows from a .Net application using the most preferred way, a native feature in SQL Server, Table Valued Parameters.

Read on:

A short introduction to Table Valued Parameters:

Parameters are place holder for values that are passed from various constructs outside of a programming artifact. We declare parameters all the time, in various technologies, and in various forms - command line arguments, query string values in ASP.NET, sql parameters that carry information to database in a type safe way, etc. In SQL Server parameters are the way to pass and receive information that needs to be dealt with, and information can come from either within SQL Server or outside of SQL Server like from a .Net application. Parameters are generally made of a primal data type like int, char, varchar etc. When such parameters are modeled on some pre-defined table type, such parameters are called Table Valued Parameters. The important words to note here are “table type”. Not table, but table type, which means a user defined type based on some table structure.

Table Valued Parameters have been supported by SQL Server since version 2008.

To demonstrate the concept of TVPs, I will be using a very simple data model consisting of three tables: Student, Course and an association table supporting many-to-many relationship between Student and Course, StudentCourse.

The Entity-Relationship diagram will clarify the relationship between the tables:

ERD diagram:

ERD diagram

 

 

 

 

 

 

 

According the ER diagram, a student can take many courses and a course can be taken by many students. The insertion of courses that a student is interested in the association table is an ideal application of this technique.

Now consider the following code to make a table type. this type will be used to model a table valued parameter on the table type:

   1:  CREATE TYPE StudentCoursesTableType AS Table
   2:  ([StudentID] [int] NULL,
   3:   [CourseID] [int] NULL);

 

Making a table type makes the type available in the User-Defined Table Types sub-section of Types section.

clip_image002

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

 

Execution of the following code should give you some result depending on what you have available in the StudentCourse table.

   1:  Declare @StudentCoursesTVP as StudentCoursesTableType;
   2:   
   3:  Insert into @StudentCoursesTVP(StudentID, CourseID)
   4:  Select [StudentID], [CourseID] from [dbo].[StudentCourse];
   5:   
   6:  Select * from @StudentCoursesTVP;
 
 

clip_image002[5]

 

 

 

 

 

 

 

 

 

 

 

So now that we are through with the basics of TVP, let’s see how we can use them in our main purpose of processing multiple rows of data. To demonstrate this, I will be using a simple web form application powered by the same data model discussed above. The application helps a student get enroll in the course(s) of his/her choice.

clip_image004

 

 

 

 

 

 

 

 

 

 

 

 

The coding for the webpage is very simple. The pseudo-code is as follows:

1. Select a student from the drop down.

2. Select from the available courses that the student needs enrollment for.

3. Click on the submit button.

I am going to leave it up to the reader to understand the programming in the web application. It is straight forward and the domain model powering the application is a reflection of the data model depicted above.

The main work is being done at two places:

1. Web application’s repository method which parses the incoming object data into a datatable.

2. The stored procedure responsible for receiving the data in the form of a table valued parameter and using it to feed data into the desired table.

Consider the following repository method in the StudentSQLRepository class:

   1:  public int GetEnrolled(List<Course> courses, int studentID)
   2:          {
   3:              DataTable table = new DataTable("data");
   4:              table.Columns.Add("StudentID");
   5:              table.Columns.Add("CourseID");
   6:              foreach (Course course in courses)
   7:              {
   8:                  table.Rows.Add(new object[] { studentID, course.CourseID});
   9:              }
  10:              string sql = @"dbo.EnrollStudentInCourses";
  11:              int result = 0;
  12:              SqlParameter studentCoursesTVP = new SqlParameter("StudentCoursesTVP", table);
  13:              studentCoursesTVP.SqlDbType = SqlDbType.Structured;
  14:              using (SqlConnection connection = new SqlConnection(connectionString))
  15:              {
  16:                  using (SqlCommand command = new SqlCommand(sql, connection))
  17:                  {
  18:                      command.CommandType = CommandType.StoredProcedure;
  19:                      command.Parameters.Add(studentCoursesTVP);
  20:   
  21:                      connection.Open();
  22:                      result = command.ExecuteNonQuery();
  23:                      connection.Close();
  24:                  }
  25:              }
  26:              return result;
  27:          }

There are two noteworthy points in the code above:

1. We are passing the datatable to the SQL Server database to be processed. The datatable is modeled on the table type present in the SQL Server database, used by the table valued parameter.

2. The SqlDbtype of the SqlParameter is set to Structured type. This is strictly done to improve the readability of our code and convey meaning in an explicit way. ADO.NET will perfectly parse the datatable correctly had we not declared the SqlDbType to Structured explicitly.

Following is the SQL script of the dbo.EnrollStudentInCourses responsible for parsing the data in the @StudentCoursesTVP table valued parameter correctly.

   1:  CREATE PROCEDURE [dbo].[EnrollStudentInCourses]
   2:      
   3:      @StudentCoursesTVP StudentCoursesTableType readonly
   4:   
   5:  AS
   6:  BEGIN
   7:   
   8:      Insert into StudentCourse (StudentID, CourseID)
   9:      Select StudentID, CourseID from @StudentCoursesTVP    
  10:      
  11:  END
  12:   
  13:  GO

 

If you go and read my two other posts on inserting multiple rows using a comma separated values list and XML, you surely will come to the conclusion that using table valued parameters is the cleanest approach, that doesn’t include any code acrobatics either in .Net code or in SQL code. Not only that, table valued parameters code is highly performant as long as there’s reasonable data involved.

The sample code for this post can be downloaded from the following location:

References:

1. Table Valued Parameters at TechNet

Inserting Multiple Rows in SQL Server via a XML

15. February 2014 12:33 by Parakh in SQL Server, XML  //  Tags: , , ,   //   Comments
This post discusses how to post multiple rows worth of data to a SQL Server database using XML to minimize calls made to the database to store data.

Key take away:

My last two posts touched on the two methods available in SQL Server to flatten hierarchical XML data into flat relational form. In this post I will build upon those concepts and will cover how to leverage them to insert multiple rows worth of data into a SQL Server database in a single call.

Read on:

Hierarchical XML data can be flattened at SQL Server database level using one of the two ways:

1. OPENXML method

2. Nodes method

One of the reason why we would want to convert XML data into relational data at database level is to push in multiple rows worth of data to be inserted into a single or multiple tables in a single database call. Opening and closing a connection to a database for doing operation can be a costly affair for a website storing a sizeable amount of data at every call. The cost can be minimized by sending all the related data in a single call and parsing it out into distinct rowsets and storing them in the desired table(s). This scenario is especially true when you provide editing capabilities in a tabular or gridview kind of an environment and allow user to check in all the changes in one button click.

The technique of storing multiple rows with the help of XML works on the following strategy:

1. Convert the information into XML hierarchy.

2. Pass the XML to SQL Server.

3. Parse the hierarchy via one of the methods – OPENXML or nodes method and convert it into relational form.

4. Parse the relational form and store it via normal insert query.

To demonstrate I will be using a very simple data model consisting of three tables: Student, Course and an association table supporting many-to-many relationship between Student and Course, StudentCourse.

The Entity-Relationship diagram will clarify the relationship between the tables:

ERD diagram

 

 

 

 

 

 

 

According the ER diagram, a student can take many courses and a course can be taken by many students. The insertion of courses that a student is interested in the association table is an ideal application of this technique.

The following ASP.NET webform that is the web front end that we will use to form a complete example to demonstrate this approach:

image

 

 

 

 

 

 

 

 

 

 

 

 

The coding for the webpage is very simple. The pseudo-code is as follows:

1. Select a student from the drop down.

2. Select from the available courses that the student needs enrollment for.

3. Click on the submit button.

I am going to leave it up to the reader to understand the programming in the web application. It is straight forward and the domain model powering the application is a reflection of the data model depicted above.

The main work is being done at two places:

1. Web application’s repository method which does the work of making a hierarchical XML data from the objects.

2. The stored procedure that converts incoming XML data into relational data and stores it into table.

Consider the following repository method:

   1:  public int GetEnrolled(List<Course> courses, int studentID)
   2:          {
   3:              DataTable table = new DataTable("data");
   4:              table.Columns.Add("StudentID");
   5:              table.Columns.Add("CourseID");
   6:   
   7:              foreach (Course course in courses)
   8:              {
   9:                  table.Rows.Add(new object[] { studentID, course.CourseID});
  10:              }
  11:   
  12:              string data;
  13:              using (StringWriter sw = new StringWriter())
  14:              {
  15:                  table.WriteXml(sw);
  16:                  data = sw.ToString();
  17:              }
  18:   
  19:   
  20:              string sql = @"dbo.EnrollStudentInCourses";
  21:   
  22:              int result = 0;
  23:   
  24:              SqlParameter xml = new SqlParameter("XML", data);
  25:   
  26:              using (SqlConnection connection = new SqlConnection(connectionString))
  27:              {
  28:                  using (SqlCommand command = new SqlCommand(sql, connection))
  29:                  {
  30:                      command.CommandType = CommandType.StoredProcedure;
  31:                      command.Parameters.Add(xml);
  32:   
  33:                      connection.Open();
  34:                      result = command.ExecuteNonQuery();
  35:                      connection.Close();
  36:                  }
  37:              }
  38:   
  39:              return result;
  40:          }

 

The point of interest in the code mentioned above are the lines that push the object data into a datatable and the code that converts the datatable into an XML hierarchy. Please note that the hierarchy will include the name of the datatable that gets set in the .Net code. So please name it appropriately. The resulting XML hierarchy looks something as shown below:

   1:  <DocumentElement>
   2:      <data>
   3:          <StudentID>1</StudentID>
   4:          <CourseID>4</CourseID>
   5:      </data>
   6:      <data>
   7:          <StudentID>1</StudentID>
   8:          <CourseID>5</CourseID>
   9:      </data>
  10:      <data>
  11:          <StudentID>1</StudentID>
  12:          <CourseID>6</CourseID>
  13:      </data>
  14:  </DocumentElement>

It is this XML that gets passed to the SQL Server and is de-serialized into relational form using the nodes method. I have discussed the fundamentals of the nodes method in my last post. The de-serialization can also be carried out by using the OPENXML method.

The core of the dbo.EnrollStudentInCourses stored procedure, responsible for recording the course enrollment data for a student is made of the following code:

   1:  Insert into StudentCourse (StudentID, CourseID)
   2:  SELECT
   3:  data.value('(StudentID/text())[1]','int') as StudentID,
   4:  data.value('(CourseID/text())[1]','int') as CourseID
   5:  FROM @XML.nodes('/DocumentElement/data')
   6:  as StudentCourses(data)
 

NOTE: The SQL code is made keeping in mind the name of the datatable used to capture the data in the .Net code.

The sample code for this post consists of the web application and the powering database. Download it from:

Converting XML data into Relational Form using nodes method

2. November 2013 11:40 by Parakh in SQL Server, XML  //  Tags: , ,   //   Comments
This post describes how to convert XML data into relational form using the nodes method available in SQL Server.

Key take away:

In my last post I covered the topic of converting XML data into relational form using OPENXML function available in SQL Server. In this post I will be covering a second way of converting XML data into relational form using the nodes method. Nodes method, like OPENXML function, uses a valid XQuery expression to parse through XML hierarchy, but offers a bit more flexibility and in general is more readable. This post is a prelude to the forthcoming post on the topic of inserting multiple rows in SQL Server database table via XML.

Read on:

There are sometimes requirements that dictate XML data be sent to the database and de-serialized to be stored in relational form at the database itself. There are two methods available to achieve this in SQL Server – OPENXML function and nodes method for XML data type. I have described using an example on how to flatten XML data to relational using OPENXML function in my previous post. In this post I will describe doing same using nodes method available for XML data type in SQL Server.

Nodes method approach:

The nodes method is a rowset provider just like a table or a view which allows access to XML data in relational form. The nodes method is applicable on XML data type and takes a valid XQuery representing the portion of XML data which is desired to be flattened out into relational form. Unlike the OPENXML function, there’s no requirement in the nodes approach to prepare an in-memory representation of the XML data. Thus there are no system stored procedures that you have to run to create and wipe off the intermediate in-memory representation of data. This results in a clean, self-sufficient and a more readable query. Let’s take an example and see the nodes method in action.

Consider the following code:

DECLARE @XML xml = 
'<Students>
    <Student id="1">
        <FName>Parakh</FName>
        <LName>Singhal</LName>
        <Age>30</Age>
        <Courses>
            <Course id="1">Fundamentals of Databases</Course>
            <Course id="10">Fundamentals of Networking</Course>
            <Course id="15">Fundamentals of Security</Course>
        </Courses>
    </Student>
    <Student id="2">
        <FName>Glen</FName>
        <LName>Bennet</LName>
        <Age>31</Age>
        <Courses>
            <Course id="12">Fundamentals of Data Warehousing</Course>
            <Course id="15">Fundamentals of Security</Course>
        </Courses>
    </Student>    
</Students>';
 
SELECT
Student.value('@id','int') as StudentID,
Student.value('(FName/text())[1]','varchar(50)') as StudentFirstName,
Student.value('(LName/text())[1]','varchar(50)') as StudentLastName,
Student.value('(Age/text())[1]','int') as StudentAge,
Student.value('(Courses/Course/text())[1]','varchar(50)') as EnrolledCourse1,
Student.value('(Courses/Course/text())[2]','varchar(50)') as EnrolledCourse2,
Student.value('(Courses/Course/text())[3]','varchar(50)') as EnrolledCourse3
FROM @XML.nodes('/Students/Student')
as StudentTable(Student)

This gives us the following result:

SQl Result nodes method

Explanation of code:

The sample XML data is a collection of students under the appropriately named root node “Students”. Each “Student” node further consists of information about the student and the courses that he’s enrolled in. The sample XML is sufficiently complex to give us an opportunity to learn the following;

a) How to query data available in the form of attribute of an element like “id” of a student.

b) How to query various node elements like “FName”,” LName” and “Age”.

c) How to query a hierarchy available in the form of “Course” information.

Our code takes the XML type variable and uses the instance of nodes method available per the semantics of XML data type in SQL Server. We extract the hierarchy from the XML type variable in the FROM clause by providing the right XQuery path, and aliased the returned rowset as StudentTable with a single column Student. It is this Student that we have to use in conjunction with the value method to extract the data desired.

The syntax to extract attribute values requires using the “@” symbol suffixed with the name of the attribute as it appears in the XML hierarchy. The values of various elements in the hierarchy can be extracted by using their names, the form of data they need to be extracted as like text() and a valid data type available in SQL Server compatible to be used in the rowset form, like varchar, int, char etc. When there is multiple rows worth of data in the XML hierarchy, we have to use metadata property for elements in XML hierarchy to denote the occurrence that needs to be extracted.

For example,

Student.value('(FName/text())[1]','varchar(50)') as StudentFirstName

 

means that we want to extract the data in the “FName” element as varchar(50) data type and we want to extract data corresponding to EVERY first occurrence of the “FName” element in the XML hierarchy. So that means that if there is a second occurrence of the “FName” element in the XML hierarchy, our sql query is going to ignore it. The “Courses” portion of the sql query is a good example to drive home the point. Over there we have to mention explicitly about which occurrence of “Course” we want to extract the data of. Play with it and see how it will give you different results.

I feel that sql query formed using the nodes method is more readable, less scary than the query formed using the OPENXML function.

In my next post I will be covering the topic that my two posts on processing XML data to relational data leads to, i.e. inserting multiple rows worth of data into SQL Server in a single call, using the XML approach from a sample ASP.NET web application.

NOTE: There is a lot of debate going on internet as to which way of shredding XML data to relational form is more efficient – OPENXML function or the nodes method. I believe that this varies from case to case, and should be best judged after doing a thorough analysis with different sets of expected conditions.

References:

1. Nodes method at Technet

2. Flattening XML data in SQL Server

3. XML at W3c Schools

Month List

ParakhSinghal@Twitter.com

Note: For Customization and Configuration, CheckOut Recent Tweets Documentation