When you are using SQL Server stored procedures, you get a lot of flexibility in your code - changing the code doesn't need a recompile, deploying the new or updated procedures is as easy as sending and running text scripts, and so on. I won't enter on the pros and cons of keeping code in the database, as this will open a very long discussion, with no winners.
In this article, I will focus on one aspect of the SQL Server code, the lack of rigid rules for the code. It all starts with being case insensitive, something like "SELECT from customer" is the same of "select FROM customer". It's not a great deal, but when you have a lot of stored procedures and many people maintaining it, you may need to enforce some standards. In this article I will show you how to use C# to parse SQL Server code and enforce some coding standards in your SQL Server procedures.
Retrieving the stored procedures from the database
The first step for processing the stored procedures is to retrieve them from the database. For this article, we will be using the WorldWideImporters sample database, that can be downloaded from .
To get the names of all procedures in the database, you must use a command like this one:
select s.name+'.'+p.name as name from sys.procedures p
inner join sys.schemas s on p.schema_id = s.schema_id
order by name
Once you have the names of all the procedures in the database, you can get their code with the procedure sys.sp_helpText, passing the procedure name as a parameter. This code will get all procedures from the database and store them in a list:
static void Main()
{
using (var con = new SqlConnection("Server=.;Database=WideWorldImporters;Trusted_Connection=True;"))
{
con.Open();
var procTexts = GetStoredProcedures(con).Select(n => new {ProcName = n, ProcText = GetProcText(con, n)}).ToList();
}
}
private static List<string> GetStoredProcedures(SqlConnection con)
{
using (SqlCommand sqlCommand = new SqlCommand("select s.name+'.'+p.name as name from sys.procedures p " +
"inner join sys.schemas s on p.schema_id = s.schema_id order by name", con))
{
using (DataTable procs = new DataTable())
{
procs.Load(sqlCommand.ExecuteReader());
return procs.Rows.OfType<DataRow>().Select(r => r.Field<String>("name")).ToList();
}
}
}
private static string GetProcText(SqlConnection con, string procName)
{
using (SqlCommand sqlCommand = new SqlCommand("sys.sp_helpText", con)
{
CommandType = CommandType.StoredProcedure
})
{
sqlCommand.Parameters.AddWithValue("@objname", procName);
using (var proc = new DataTable())
{
try
{
proc.Load(sqlCommand.ExecuteReader());
return string.Join("", proc.Rows.OfType<DataRow>().Select(r => r.Field<string>("Text")));
}
catch (SqlException)
{
return null;
}
}
}
}
This code will open a connection to the database, get all procedure names and then get their text, returning a list of an anonymous class with two members: ProcName and ProcText. You can then process all the procedures in the database.
Parsing the procedures
The next step is to parse the procedures to split into the containing parts. This is not an easy task to make from scratch. The SQL Server language is not easy and evolves with each version of SQL Server. There are many ways to do the same thing, so writing a parser is not something I would recommend. Fortunately, Microsoft has already written a parser for us, and it's made available via NuGet package. To use it, just add the Microsoft.SqlServer.TransactSql.ScriptDom package to your app. When you add the NuGet package to the app you will see it's not an official package: this dll is part of a larger package, Microsoft.SqlServer.DacFx.x64 and it's there only to make the number of dlls added smaller.
Once you add the package, you can use this code to parse the code of the procedure:
private static (TSqlFragment sqlTree, IList<ParseError> errors) ParseSql(string procText)
{
var parser = new TSql150Parser(true);
using (var textReader = new StringReader(procText))
{
var sqlTree = parser.Parse(textReader, out var errors);
return (sqlTree, errors);
}
}
This method uses a new feature of C# 7.0, ValueTuples. If you are using .NET version 4.7 or higher, you don't need to add anything to use it. If you are using an older version, you must add the System.ValueTuple NuGet package to your project. At the beginning, we instantiate a TSql150Parser class. Depending on the version of SQL server that you want to parse, you can choose a different parser class. Then, we call the Parse method, that will parse the code, return any errors in the errors variable and return a TSqlFragment with the parsed data. Just with this simple code, you already have many benefits: you can parse the procedure for many versions of SQL Server, check if the procedure has errors in it and parse the procedure into its components. The returned tree is of type TSqlScript, that has some interesting properties:
- Batches - gets the batches in the procedure, so you can process them individually
- FirstTokenIndex - shows where the fragment begins - for the script, it usually starts at 0, but when you are working with other kinds of fragments, that may not be the case
- FragmentLength - size of the fragment, in bytes
- LastTokenIndex - shows where the fragment ends
- ScriptTokenStream - the list of parsed tokens
- StartColumn - start column of the fragment
- StartLine - start line of the fragment
- Offset - offset in bytes from the start
As you can see, there is already a lot of information there. When you take a look at the ScriptTokenStream, you can see a lot more there:
The SQL code is parsed into tokens and every token is categorized. With this code, you can group the tokens and have brief statistics of your code:
static void Main()
{
using (var con = new SqlConnection("Server=.;Database=WideWorldImporters;Trusted_Connection=True;"))
{
con.Open();
var procTexts = GetStoredProcedures(con).Select(n =>
new { ProcName = n, ProcText = GetProcText(con, n) }).ToList();
var procTrees = procTexts.Select(p =>
{
var processed = ParseSql(p.ProcText);
return new { p.ProcName, processed.sqlTree, processed.errors };
});
var procStats = procTrees
.SelectMany(p => p.sqlTree.ScriptTokenStream)
.GroupBy(t => t.TokenType)
.Select(g => new { Key = g.Key, Count = g.Count()})
.OrderByDescending(g => g.Count);
}
}
With this code, we can see something like this in the database:
WhiteSpace 15693
Identifier 3571
Variable 1976
Plus 1667
UnicodeStringLiteral 1192
Dot 1085
Semicolon 1051
Comma 957
LeftParenthesis 937
RightParenthesis 937
We can see the variable names used with this code:
static void Main()
{
using (var con = new SqlConnection("Server=.;Database=WideWorldImporters;Trusted_Connection=True;"))
{
con.Open();
var procTexts = GetStoredProcedures(con).Select(n =>
new { ProcName = n, ProcText = GetProcText(con, n) }).ToList();
var procTrees = procTexts.Select(p =>
{
var processed = ParseSql(p.ProcText);
return new { p.ProcName, processed.sqlTree, processed.errors };
});
var procVariables = procTrees
.SelectMany(p => p.sqlTree.ScriptTokenStream)
.Where(t => t.TokenType == TSqlTokenType.Variable)
.GroupBy(t => t.Text)
.Select(g => g.Key)
.OrderBy(t => t);
}
}
If you run this code, you will see that, although there are 1976 tokens of type Variable, there are only 76 different names used.One thing that called me my attention is that there are two similar variables used, @Crlf and @CrLf. We can use this parsing to know in which procedures these variables are used. Note that this is different than a text search: a text search could find the variables inside a comment or in a string. In this case, we will only find the real SQL variables:
static void Main()
{
using (var con = new SqlConnection("Server=.;Database=WideWorldImporters;Trusted_Connection=True;"))
{
con.Open();
var procTexts = GetStoredProcedures(con).Select(n => new { ProcName = n, ProcText = GetProcText(con, n) }).ToList();
var procTrees = procTexts.Select(p =>
{
var processed = ParseSql(p.ProcText);
return new { p.ProcName, processed.sqlTree, processed.errors };
});
Func<TSqlParserToken, bool> queryVariables = t => t.TokenType == TSqlTokenType.Variable
&& (t.Text == "@CrLf" || t.Text == "@Crlf");
var variablesFound = procTrees
.Where(p => p.sqlTree.ScriptTokenStream.Any(queryVariables))
.Select(t => new { t.ProcName, FoundVariables = t.sqlTree.ScriptTokenStream.Where(queryVariables)});
}
}
If you run this code, you will see that most of the variables is written as @CrLf, while some are written as @Crlf. We will change all variables to @CrLf with this code:
static void Main()
{
using (var con = new SqlConnection("Server=.;Database=WideWorldImporters;Trusted_Connection=True;"))
{
con.Open();
var procTexts = GetStoredProcedures(con).Select(n => new { ProcName = n, ProcText = GetProcText(con, n) }).ToList();
var procTrees = procTexts.Select(p =>
{
var processed = ParseSql(p.ProcText);
return new { p.ProcName, processed.sqlTree, processed.errors };
});
var variablesFound = procTrees
.Where(p => p.sqlTree.ScriptTokenStream.Any(queryVariables))
.Select(t => new { t.ProcName, FoundVariables = t.sqlTree.ScriptTokenStream.Where(queryVariables)});
foreach (var procName in variablesFound.Select(p => p.ProcName))
{
var sqlTree = procTrees.First(p => p.ProcName == procName).sqlTree;
foreach (var token in sqlTree.ScriptTokenStream.Where(t => t.Text == "@Crlf"))
{
token.Text = "@CrLf";
}
var changedSql = string.Join("", sqlTree.ScriptTokenStream.Select(t => t.Text).ToArray());
}
}
}
ChangedSql has the changed SQL, that can be applied to the database, making the variable names uniform.
Conclusions
As you can see, you can do a lot with this parser, like have statistics, change variable names and so on. But still we haven't scratched the surface of what can be done with the parser. We will see more in the next article. See you then!
2 thoughts on “Parsing Sql Server code with C#”