CRUD procedures represent a good way how to secure the database. When using CRUD procedures, no user has direct access to the database tables and instead of this is forced to use parameterized procedures for all data manipulations called CRUD procedures. CRUD is acronym for Create Read Update Delete.
CRUD procedures have a lot of advantages from which I can name several:
- You do not need to grant rights directly to tables and in this way you hide the physical tables structure to users.
- You can encapsulate some logic into the procedures and then when something needs to be changed, you simply modify a procedure and do not need to rebuild the application.
- You hide the SQL logic encapsulated in stored procedures from end user.
- You protect your SQL server against SQL injection as all data using the CRUD procedures has to be passed as parameters and in this way you drastically decrease a chance for the SQL injection.
The main disadvantage of CRUD procedures is the overhead which SQL developer has to do as for each table or group of several tables it is necessary separate stored procedures for the data manipulation.
There are several tools and plugins into visual studio, which simplifies creation of the CRUD procedures, but in this article I would like to show a possible way how to automate creation of the CRUD procedures using pure T-SQL.
The automation will be handled by a custom system stored procedure, which generate all the necessary code or directly create all the CRUD procedures for a database table.
This article describes how to crate a system stored procedure sp_makeCRUD
, which will take 4 parameters @objectName
, @executionMode
, @dropExistingProcedures
and @outputIdentityCalcField
. The @objectName
represents a table for which the CRUD procedures will be generated, @executionMode
will represents execution mode of the stored procedure and will control whether the code of CRUD procedures will be only printed on scree or whether the generated code will be automatically executed and the CRUD procedures will created. @dropExistingProcedures
parameter will specify whether include DROP
statement for all procedures to drop eventual existing procedures and @outputIdentityCalcField
will control, whether Identity and Calculated fields will be automatically returned as record set for ISERT
and UPDATE
operations.
CRUD procedures construction
To create a CRUD procedures we need to know all the fields in the table, whether the fields are Identity or calculated fields and also we need to know what fields the primary key is composed from. Also table name and it’s schema will be needed as user can specify the object name without schema or with schema. The CRUD procedures will be created in the same schema as the original table. To retrieve such information various system tables will be used.
Retrieving Object ID, Table Name, Schema Name and DB Name
To retrieve Object ID (ID of the table) and DB Name we will use the OBJECT_ID() and DB_NAME() functions.
SELECT
@objID = OBJECT_ID(@objectName),
@dbName = DB_NAME()
Table name and schema name, could be retrieved using system tables sys.objects
and sys.schemas
.
SELECT
@schemaName = s.name,
@tableName = o.name
FROM sys.objects o
INNER JOIN sys.schemas s ON o.schema_id = s.schema_id
WHERE o.object_id = @objId AND o.type = 'U'
Retrieving Table Field and Primary Key
After the object ID is retrieved, it is necessary to retrieve all the table fields, their data types and information whether the field is an IDENTITY field or whether it is Calculated Field. This information is necessary for generating INSERT and UPDATE statements as such fields are not updatable. Also it is necessary to identify fields which are part of the primary key. This fields are necessary for the UPDATE, DELETE and also for SELECT One statements. Fields will be temporarily stored in table variables as they will be accessed several times to construct different fields combinations for each statement and also for creation of procedure parameters.
The retrieval of all fields is quite easy as only access to sys.columns
table for field names and sys.types
for type names is necessary. The field type is written to the table variable as SQL statement which will be used when generating the procedure parameters.
DECLARE @allFields TABLE ( --Table variable for storing all the table fields
name sysname, --field name
isIdentity bit, --specifies whether field is INDENTITY
isCalculated bit, --specifies whether filed is Calculated field
fieldType sysname --Specified data type of the field
)
--Get all table fields and store them in the @allFields table variable for construction of CRUD procedures
INSERT INTO @allFields (
name,
isIdentity,
isCalculated,
fieldType
)
SELECT
c.name,
is_identity,
is_computed,
CASE
WHEN t.name IN (N'char', N'nchar', N'varchar', N'nvarchar') THEN QUOTENAME(t.name) + N'(' + CASE WHEN c.max_length = -1 THEN N'max' ELSE CAST(c.max_length AS sysname) END + N')'
WHEN t.name IN (N'decimal', N'numeric') THEN QUOTENAME(t.name) + N'(' + CAST(c.precision AS sysname) + N', ' + CAST(c.scale AS sysname) + N')'
ELSE QUOTENAME(t.name)
END
FROM sys.columns c
INNER JOIN sys.types t ON c.user_type_id = t.user_type_id
WHERE object_id = @objId
The query to retrieve the fields form which the Primary Key is composed is more complex and to retrieve all the information we need it is necessary to access several system tables. As the Primary Key is enforced by a unique index, the field names can be found using the ID of the columns in unique index by which the primary key is enforced.
DECLARE @pkFields TABLE ( --Table variable for storing fields which are part of primary key
name sysname, --field Name
fieldType sysname --Specified data type of the field
)
--Get list of Primary Key Fields and store them in @pkFields table variable for construction of CRUD procedures
INSERT INTO @pkFields(
name,
fieldType
)
SELECT
c.name,
CASE
WHEN t.name IN (N'char', N'nchar', N'varchar', N'nvarchar') THEN QUOTENAME(t.name) + N'(' + CASE WHEN c.max_length = -1 THEN N'max' ELSE CAST(c.max_length AS sysname) END + N')'
WHEN t.name IN (N'decimal', N'numeric') THEN QUOTENAME(t.name) + N'(' + CAST(c.precision AS sysname) + N', ' + CAST(c.scale AS sysname) + N')'
ELSE QUOTENAME(t.name)
END
FROM sys.key_constraints kc
INNER JOIN sys.indexes i ON kc.parent_object_id = i.object_id AND kc.unique_index_id = i.index_id
INNER JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
INNER JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
INNER JOIN sys.types t ON c.user_type_id = t.user_type_id
WHERE kc.parent_object_id = @objId and kc.type = 'PK'
Generating Columns and Variables Lists
Once the list of all columns is retrieved, the lists of different columns combinations could be generated. For this purpose a SELECT statement with FOR XML PATH clause will be used as this clause greatly simplifies a CSV list generation on SQL 2005 and above. Below is a code for the All Columns
SELECT @allColumns =
STUFF(REPLACE((SELECT
N' ' + @crlf + N' ,' + QUOTENAME(c.name)
FROM @allFields c
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 27, N' ')
The spaces are included in the generated string for later final query formatting as it allows the query to be printed in readable form and also when a stored procedure will be generated, it can be later easily modified as the query will contain correct line breaks and indentation. The REPLACE function is used to replace the XML representation of CRLF back to real CRLF characters as the FOR XML PATH in reality produces XML output and translates all the CRLF characters to their XML compliant equivalents.
Generating code of CRUD Procedures
Once all the the combination of columns are generated, the variables with such fields and parameters list can be used to generate the final CRUD procedure. Below is a snippet representing a SELECT procedure.
SET @sql = N'-- =======================================================
-- Author: ' + QUOTENAME(SUSER_SNAME()) + N'
-- Create date: ' + CONVERT(nvarchar(10), GETDATE(), 111) + N'
-- Description: Selects records from table ' + QUOTENAME(@schemaName) + '.' + QUOTENAME(@tableName) + N'
-- =======================================================
CREATE PROCEDURE ' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixSelect + N']
' + @selectParams + N'
AS
BEGIN
SET NOCOUNT ON;
IF (' + @selectAllIfNullCondition + N') THEN
BEGIN
SELECT
' + @allColumns + N'
FROM ' + QUOTENAME(@schemaName) + N'.' + QUOTENAME(@tableName) + N'
END
ELSE
BEGIN
SELECT
' + @allColumns + N'
FROM ' + QUOTENAME(@schemaName) + N'.' + QUOTENAME(@tableName) + N'
WHERE
' + @selectCondition + N'
END
END
GO
';
sp_makeCRUD Final Form
Once all the parts of the procedure are prepared it’s possible to construct a final form of the sp_makeCRUD procedure. Below is a complete code for the sp_makeCRUD procedure.
USE [master]
GO
--==========================================================
-- Author: (c) 2011 Pavel Pawlowski
-- Description: Generates CRUD procedures for a table
--
--@objectName = table name with or without schema for which the CRUD procedures should be generated
--
--@executionMode
-- 1 = Print the script Only
-- 2 = Output the script as recordset using SELECT for longer procedures which is not possible output using PRINT
-- 4 = Execute and Commit
-- 8 = Execute and Rollback - testing mode
--
--@dropExistingProcedures = 1 | 0
-- specifies whether generate DROP commands for existing objects
--
--@outputIndentityCalcFields = 1 | 0
-- specifies whether Identity and Calculated fields should be OUTPUTed in INSERT and UPDATE
--==========================================================
CREATE PROCEDURE [dbo].[sp_makeCRUD]
@objectName sysname,
@executionMode tinyint = 1,
@dropExistingProcedures bit = 1,
@outputIndentityCalcFields bit = 1
AS
BEGIN
SET NOCOUNT ON;
SET XACT_ABORT ON;
--variables declaration
DECLARE
@objId int, --ID of the Table
@schemaName sysname, --schema Name of the Table
@tableName sysname, --TableName
@dbName sysname, --Database name in which we are creating the procedures
@crlfXML nchar(7), --XML representation of the CLRF
@crlf nchar(2), --CLRF characters
@procPrefix sysname, --CRUD procedures Prefix
@sql nvarchar(max), --SQL code for particular steps
@msg nvarchar(max), --A message
@suffixSelect sysname, --Suffix for SELECT procedure
@suffixUpdate sysname, --Suffix for UPDATE procedure
@suffixDelete sysname, --Suffix for Delete procedure
@suffixInsert sysname, --Suffix for INSERT procedure
@selectParams nvarchar(max), --Parameters for SELECT procedure
@allColumns nvarchar(max), --List of All columns in a table for SELECT statement
@selectAllIfNullCondition nvarchar(max), --Condition for checking if all parameters in SELECT procedure are NULL
@selectCondition nvarchar(max), --SELECT statement condition
@updateParams nvarchar(max), --Parameters for UPDATE procedure
@updateColumns nvarchar(max), --List of columns for UPDATE statement
@updateDeleteCondition nvarchar(max), --Condition for UPDATE and DELETE statement
@updateOutputCols nvarchar(max), --List of UPDATE statement output columns to output calculated columns
@deleteParams nvarchar(max), --Parameters for DELETE procedure
@insertParams nvarchar(max), --Parameters for INSERT procedure
@insertColumns nvarchar(max), --List of COLUMNS for INSERT statement
@insertOutputCols nvarchar(max), --List of INSERT statement ouptup columns to output IDENTITY and calculated fields
@insertParamNames nvarchar(max), --List of parameter names in Insert procedure
@isTooLongForPrint bit --Sores info whether some of the procs is too long for PRINT
--Declaration of fields Table Variables
DECLARE @pkFields TABLE ( --Table variable for storing fields which are part of primary key
name sysname, --field Name
fieldType sysname --Specified data type of the field
)
DECLARE @allFields TABLE (
name sysname, --field name
isIdentity bit, --specifies whether field is INDENTITY
isCalculated bit, --specifies whether filed is Calculated field
fieldType sysname --Specified data type of the field
)
--Table variable for storing scripts for execution
DECLARE @scripts TABLE (
id int NOT NULL IDENTITY,
script nvarchar(max)
)
--Check if an execution mode is selected
IF ((@executionMode & 7) = 0)
BEGIN
SET @msg = N'You have to select at at leas one possible execution Mode (@executionMode)
1 = Print the script Only
2 = Output the script as SELECT resordset for longer procedures which is not possible output using PRINT
4 = Execute and Commit
8 = Execute and Rollback - testing mode
You can also combine the Print and Execute Modes, but you cannot combine both execution modes'
RAISERROR (@msg, 11, 1)
RETURN
END
IF ((@executionMode & 6) = 6)
BEGIN
SET @msg = N'You cannot specify Execute and Commit with Execute and Rollback Together'
RAISERROR (@msg, 11, 1)
RETURN
END
--populate parameters and constants
SELECT
@objID = OBJECT_ID(@objectName),
@dbName = DB_NAME(),
@crlfXML = N'
' + NCHAR(10), --XML Representation of the CR+LF delimiter as we use FOR XML PATH ant this translates the original CR+LF to XML Equivalent. We need it to change it back
@crlf = NCHAR(13) + NCHAR(10), --CR+LF delimiter used in script
@procPrefix = 'usp_CRUD_', --Specifies prefix to be added to all CRUD procedures
@suffixSelect = '_S', --Specifies suffix to be added to the Select Procedure
@suffixUpdate = '_U', --Specifies suffix to be added to the Update Procedure
@suffixDelete = '_D', --Specifies suffix to be added to the Delete Procedure
@suffixInsert = '_I' --Specifies suffix to be added to the Inser Procedure
--Check whether object exists
IF @objId IS NULL
BEGIN
SET @msg = N'Object "' + @objectName + '" doesnt'' exist in database ' + QUOTENAME(@dbName)
RAISERROR (@msg, 11, 1)
RETURN
END
--Populate table name and schema name
SELECT
@schemaName = s.name,
@tableName = o.name
FROM sys.objects o
INNER JOIN sys.schemas s ON o.schema_id = s.schema_id
WHERE o.object_id = @objId AND o.type = 'U'
--check whether object is table
IF (@tableName IS NULL)
BEGIN
SET @msg = N'Object "' + @objectName + '" is not User Table. Creating CRUD procedures is possible only on User Tables.'
RAISERROR (@msg, 11, 1)
RETURN
END
--Get all table fields and store them in the @allFields table variable for construction of CRUD procedures
INSERT INTO @allFields (
name,
isIdentity,
isCalculated,
fieldType
)
SELECT
c.name,
is_identity,
is_computed,
CASE
WHEN t.name IN (N'char', N'nchar', N'varchar', N'nvarchar') THEN QUOTENAME(t.name) + N'(' + CASE WHEN c.max_length = -1 THEN N'max' ELSE CAST(c.max_length AS sysname) END + N')'
WHEN t.name IN (N'decimal', N'numeric') THEN QUOTENAME(t.name) + N'(' + CAST(c.precision AS sysname) + N', ' + CAST(c.scale AS sysname) + N')'
ELSE QUOTENAME(t.name)
END
FROM sys.columns c
INNER JOIN sys.types t ON c.user_type_id = t.user_type_id
WHERE object_id = @objId
--Get list of Primary Key Fields and store them in @pkFields table variable for construction of CRUD procedures
INSERT INTO @pkFields(
name,
fieldType
)
SELECT
c.name,
CASE
WHEN t.name IN (N'char', N'nchar', N'varchar', N'nvarchar') THEN QUOTENAME(t.name) + N'(' + CASE WHEN c.max_length = -1 THEN N'max' ELSE CAST(c.max_length AS sysname) END + N')'
WHEN t.name IN (N'decimal', N'numeric') THEN QUOTENAME(t.name) + N'(' + CAST(c.precision AS sysname) + N', ' + CAST(c.scale AS sysname) + N')'
ELSE QUOTENAME(t.name)
END
FROM sys.key_constraints kc
INNER JOIN sys.indexes i ON kc.parent_object_id = i.object_id AND kc.unique_index_id = i.index_id
INNER JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
INNER JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
INNER JOIN sys.types t ON c.user_type_id = t.user_type_id
WHERE kc.parent_object_id = @objId and kc.type = 'PK'
--Check Whether there is primary Key the CRUD works only if there is primary key in the table
IF (NOT EXISTS(SELECT 1 FROM @pkFields))
BEGIN
SET @msg = N'Table "' + @objectName + '" does not have a Primary Key. There must exists a primary key prior generating CRUD procedures.'
RAISERROR (@msg, 11, 1)
END
--list of output columns for INSERT statement (ouptup of Identity and calculated fields)
SELECT @insertOutputCols =
STUFF(REPLACE((SELECT
N' ' + @crlf + N' ,inserted.' + QUOTENAME(c.name)
FROM @allFields c
WHERE isIdentity = 1 OR isCalculated = 1
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 19, N' ')
--list of output columns for UPDATE statement (Calculated fields only)
SELECT @updateOutputCols =
STUFF(REPLACE((SELECT
N' ' + @crlf + N' ,inserted.' + QUOTENAME(c.name)
FROM @allFields c
WHERE isCalculated = 1
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 19, N' ')
--ist of all columns used in the SELECT Statement
SELECT @allColumns =
STUFF(REPLACE((SELECT
N' ' + @crlf + N' ,' + QUOTENAME(c.name)
FROM @allFields c
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 27, N' ')
--list of columns for UPDATE statement including the equal sign and variable (all columns except indentity and calculated ones)
SELECT @updateColumns =
STUFF(REPLACE((SELECT
N' ' + @crlf + N' ,' + QUOTENAME(c.name) + N' = @' + c.name
FROM @allFields c
WHERE isIdentity = 0 AND isCalculated = 0
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 19, N' ')
--list of columns for INSERT statement (all columns except identity and calculated ones)
SELECT @insertColumns =
STUFF(REPLACE((SELECT
N' ' + @crlf + N' ,' + QUOTENAME(c.name)
FROM @allFields c
WHERE isIdentity = 0 AND isCalculated = 0
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 19, N' ')
--condition for UPDATE and DELETE statement
SET @updateDeleteCondition =
STUFF(REPLACE((SELECT
N' ' + @crlf + N' AND' + @crlf + ' ' + QUOTENAME(c.name) + N' = @' + c.name
FROM @pkFields c
FOR XML PATH(N'')), @crlfXML, @crlf), 1, 23, N'')
--IF condition for SELECT statement if all params will be NULL to do not use condition to receive better plans
SET @selectAllIfNullCondition =
STUFF((SELECT
N' AND @' + c.name + N' IS NULL'
FROM @pkFields c
FOR XML PATH(N'')), 1, 5, N'')
--Select condition (for SELECT ONE)
SET @selectCondition =
STUFF(REPLACE((SELECT
N' ' + @crlf + N' AND' + @crlf + N' (@' + c.name + N' IS NULL OR ' + QUOTENAME(c.name) + N' = @' + c.name + N')'
FROM @pkFields c
FOR XML PATH(N'')), @crlfXML, @crlf), 1, 31, N'')
--parameters list for SELECT CRUD procedure
SELECT @selectParams =
STUFF(REPLACE((SELECT
N', ' + @crlf + N' @' + c.name + N' ' + c.fieldType + N' = NULL'
FROM @pkFields c
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 11, N' ')
--parameters list for DELETE CRUD procedure
SELECT @deleteParams =
STUFF(REPLACE((SELECT
N', ' + @crlf + N' @' + c.name + N' ' + c.fieldType
FROM @pkFields c
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 11, N' ')
--parameters list for UPDATE CRUD procedure
SELECT @updateParams =
STUFF(REPLACE((SELECT
N', ' + @crlf + N' @' + c.name + N' ' + c.fieldType
FROM @allFields c
LEFT JOIN @pkFields pk ON c.name = pk.name
WHERE (c.isIdentity = 0 AND c.isCalculated = 0) OR pk.name IS NOT NULL
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 11, N' ')
--parameters list for INSERT CRUD procedure
SELECT @insertParams =
STUFF(REPLACE((SELECT
N', ' + @crlf + N' @' + c.name + N' ' + c.fieldType
FROM @allFields c
LEFT JOIN @pkFields pk ON c.name = pk.name
WHERE c.isIdentity = 0 AND c.isCalculated = 0
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 11, N' ')
--parameter names list for INSERT command in the INSERT CRUD procedure
SELECT @insertParamNames =
STUFF(REPLACE((SELECT
N' ' + @crlf + N' ,@' + c.name
FROM @allFields c
LEFT JOIN @pkFields pk ON c.name = pk.name
WHERE c.isIdentity = 0 AND c.isCalculated = 0
FOR XML PATH(N'')
),
@crlfXML, @crlf),
1, 19, N' ')
--USE DB
SET @sql = N'USE ' + QUOTENAME(@dbName) + N'
'
INSERT INTO @scripts(script) VALUES(@sql)
--SELECT PROCEDURE
IF (@dropExistingProcedures = 1)
BEGIN
SET @sql = N'--Drop existing SELECT CRUD Procedure
IF (EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(''' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixSelect + N']'') AND type = ''P''))
DROP PROCEDURE ' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixSelect +N']
'
INSERT INTO @scripts(script) VALUES(@sql)
END
SET @sql = N'-- =======================================================
-- Author: ' + QUOTENAME(SUSER_SNAME()) + N'
-- Create date: ' + CONVERT(nvarchar(10), GETDATE(), 111) + N'
-- Description: Selects records from table ' + QUOTENAME(@schemaName) + '.' + QUOTENAME(@tableName) + N'
-- =======================================================
CREATE PROCEDURE ' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixSelect + N']
' + @selectParams + N'
AS
BEGIN
SET NOCOUNT ON;
IF (' + @selectAllIfNullCondition + N')
BEGIN
SELECT
' + @allColumns + N'
FROM ' + QUOTENAME(@schemaName) + N'.' + QUOTENAME(@tableName) + N'
END
ELSE
BEGIN
SELECT
' + @allColumns + N'
FROM ' + QUOTENAME(@schemaName) + N'.' + QUOTENAME(@tableName) + N'
WHERE
' + @selectCondition + N'
END
END
';
INSERT INTO @scripts(script) VALUES(@sql)
--UPDATE PROCEDURE
IF (@dropExistingProcedures = 1)
BEGIN
SET @sql = N'--Drop existing UPDATE CRUD Procedure
IF (EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(''' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixUpdate + N']'') AND type = ''P''))
DROP PROCEDURE ' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixUpdate + N']
'
INSERT INTO @scripts(script) VALUES(@sql)
END
SET @sql = N'-- =======================================================
-- Author: ' + QUOTENAME(SUSER_SNAME()) + N'
-- Create date: ' + CONVERT(nvarchar(10), GETDATE(), 111) + N'
-- Description: Updates record in table ' + QUOTENAME(@schemaName) + '.' + QUOTENAME(@tableName) + N'
-- =======================================================
CREATE PROCEDURE ' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixUpdate + N']
' + @updateParams + N'
AS
BEGIN
SET NOCOUNT ON;
UPDATE ' + QUOTENAME(@schemaName) + N'.' + QUOTENAME(@tableName) + N' SET
' + @updateColumns + CASE WHEN @outputIndentityCalcFields = 1 AND @updateOutputCols <> N'' AND @updateOutputCols IS NOT NULL THEN N'
OUTPUT
' + @updateOutputCols
ELSE N'' END + N'
WHERE
' + @updateDeleteCondition + N'
END
';
INSERT INTO @scripts(script) VALUES(@sql)
--DELETE PROCEDURE
IF (@dropExistingProcedures = 1)
BEGIN
SET @sql = N'--Drop existing DELETE CRUD Procedure
IF (EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(''' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixDelete + N']'') AND type = ''P''))
DROP PROCEDURE ' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixDelete + N']
'
INSERT INTO @scripts(script) VALUES(@sql)
END
SET @sql = N'-- =======================================================
-- Author: ' + QUOTENAME(SUSER_SNAME()) + N'
-- Create date: ' + CONVERT(nvarchar(10), GETDATE(), 111) + N'
-- Description: Deletes recors from table ' + QUOTENAME(@schemaName) + '.' + QUOTENAME(@tableName) + N'
-- =======================================================
CREATE PROCEDURE ' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixDelete + N']
' + @deleteParams + N'
AS
BEGIN
SET NOCOUNT ON;
DELETE FROM ' + QUOTENAME(@schemaName) + N'.' + QUOTENAME(@tableName) + N'
WHERE
' + @updateDeleteCondition + N'
END
';
INSERT INTO @scripts(script) VALUES(@sql)
--INSERT PROCEDURE
IF (@dropExistingProcedures = 1)
BEGIN
SET @sql = N'--Drop existing INSERT CRUD Procedure
IF (EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(''' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixInsert + N']'') AND type = ''P''))
DROP PROCEDURE ' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixInsert + N']
'
INSERT INTO @scripts(script) VALUES(@sql)
END
SET @sql = N'-- =======================================================
-- Author: ' + QUOTENAME(SUSER_SNAME()) + N'
-- Create date: ' + CONVERT(nvarchar(10), GETDATE(), 111) + N'
-- Description: Deletes recors from table ' + QUOTENAME(@schemaName) + '.' + QUOTENAME(@tableName) + N'
-- =======================================================
CREATE PROCEDURE ' + QUOTENAME(@schemaName) + N'.[' + @procPrefix + @tableName + @suffixInsert + N']
' + @insertParams + N'
AS
BEGIN
SET NOCOUNT ON;
INSERT INTO ' + QUOTENAME(@schemaName) + N'.' + QUOTENAME(@tableName) + N' (
' + @insertColumns + N'
)' + CASE WHEN @outputIndentityCalcFields = 1 AND @insertOutputCols <> N'' AND @insertOutputCols IS NOT NULL THEN N'
OUTPUT
' + @insertOutputCols
ELSE N'' END + N'
SELECT
' + @insertParamNames + N'
END
';
INSERT INTO @scripts(script) VALUES(@sql)
DECLARE cr CURSOR FAST_FORWARD FOR
SELECT script FROM @scripts ORDER BY id
--if EXECUTION mode contains 2 we should output the code using SELECT
--Script generate using the SELECT can be saved by right lick on the result and
--select Save Result AS and storing it as CSV
IF ((@executionMode & 2) = 2 OR (@isTooLongForPrint = 1 AND (@executionMode & 1) = 1))
BEGIN
SELECT script + N'GO' FROM @scripts
END
SET @isTooLongForPrint = ISNULL((SELECT 1 FROM @scripts WHERE LEN(script) > 4000), 0)
--if Execution mode contains 1 we should PRINT the statements
IF ((@executionMode & 1) = 1 AND @isTooLongForPrint = 0)
BEGIN
OPEN cr
FETCH NEXT FROM cr INTO @sql
WHILE (@@FETCH_STATUS = 0)
BEGIN
PRINT @sql
PRINT 'GO'
FETCH NEXT FROM cr INTO @sql
END
CLOSE cr
END
--Execute the statement if it should be executed
IF (( @executionMode & 4 ) = 4 OR ( @executionMode & 8 ) = 8 )
BEGIN
OPEN cr
BEGIN TRY
BEGIN TRANSACTION
FETCH NEXT FROM cr INTO @sql
WHILE (@@FETCH_STATUS = 0)
BEGIN
EXEC (@sql)
FETCH NEXT FROM cr INTO @sql
END
IF ((@executionMode & 4) = 4)
BEGIN
IF (@@TRANCOUNT > 0)
COMMIT TRANSACTION
END
ELSE
BEGIN
IF (@@TRANCOUNT > 0)
ROLLBACK TRANSACTION
END
END TRY
BEGIN CATCH
IF (@@TRANCOUNT > 0)
ROLLBACK TRANSACTION
END CATCH
END
--if cursor is open, close it
IF (cursor_status('global', 'cr') = 1)
CLOSE cr
DEALLOCATE cr
END
GO
EXECUTE sp_ms_marksystemobject 'dbo.sp_makeCRUD'
Go
The each of the SQL statement in the procedure is first stored in a table variable called @scripts for later printing and/or execution. At the end of the procedure the code is printed using a PRINT statement or using a SELECT statement which is automatically used in case the code for some CRUD procedure is longer than 4000 characters and therefore not possible to PRINT.
If Execute and Commit or Execute And Rollback was selected then the code for the CRUD procedures is also executed. The Execute and Rollback is useful for testing, that the code for the procedures is correct and working.
Procedure is created in the [master] database so it is accessible from all databases and we do not need to create it in every database.
To be fully functional, it is necessary to mark the procedure as system procedure using below command.
EXECUTE sp_ms_marksystemobject 'dbo.sp_makeCRUD'
Marking the procedure as system object is necessary as if we not mark the object, then the procedure will run in context of the database in which it was created – in this case [system] and will fail as there are not the tables for which we want to generate the CRUD procedures.
Once the procedure is marked as system object, then it executes in the context of the current database, even it is located in the [master] database.
After we create the proc, we can test it on a small example:
USE [tempdb]
GO
CREATE TABLE dbo.TestTable (
ID int NOT NULL IDENTITY(1,1) PRIMARY KEY,
Name varchar(10),
Price money,
Quantity decimal(5,2),
TotalPrice AS (Price * Quantity)
)
GO
sp_makeCRUD 'dbo.TestTable'
This will produce below code for the CRUD procedures
USE [tempdb]
GO
--Drop existing SELECT CRUD Procedure
IF (EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID('[dbo].[usp_CRUD_TestTable_S]') AND type = 'P'))
DROP PROCEDURE [dbo].[usp_CRUD_TestTable_S]
GO
-- =======================================================
-- Author: [PAVEL-PCPavel]
-- Create date: 2011/02/10
-- Description: Selects records from table [dbo].[TestTable]
-- =======================================================
CREATE PROCEDURE [dbo].[usp_CRUD_TestTable_S]
@ID [int] = NULL
AS
BEGIN
SET NOCOUNT ON;
IF (@ID IS NULL)
BEGIN
SELECT
[ID]
,[Name]
,[Price]
,[Quantity]
,[TotalPrice]
FROM [dbo].[TestTable]
END
ELSE
BEGIN
SELECT
[ID]
,[Name]
,[Price]
,[Quantity]
,[TotalPrice]
FROM [dbo].[TestTable]
WHERE
(@ID IS NULL OR [ID] = @ID)
END
END
GO
--Drop existing UPDATE CRUD Procedure
IF (EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID('[dbo].[usp_CRUD_TestTable_U]') AND type = 'P'))
DROP PROCEDURE [dbo].[usp_CRUD_TestTable_U]
GO
-- =======================================================
-- Author: [PAVEL-PCPavel]
-- Create date: 2011/02/10
-- Description: Updates record in table [dbo].[TestTable]
-- =======================================================
CREATE PROCEDURE [dbo].[usp_CRUD_TestTable_U]
@ID [int],
@Name [varchar](10),
@Price [money],
@Quantity [decimal](5, 2)
AS
BEGIN
SET NOCOUNT ON;
UPDATE [dbo].[TestTable] SET
[Name] = @Name
,[Price] = @Price
,[Quantity] = @Quantity
OUTPUT
inserted.[TotalPrice]
WHERE
[ID] = @ID
END
GO
--Drop existing DELETE CRUD Procedure
IF (EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID('[dbo].[usp_CRUD_TestTable_D]') AND type = 'P'))
DROP PROCEDURE [dbo].[usp_CRUD_TestTable_D]
GO
-- =======================================================
-- Author: [PAVEL-PCPavel]
-- Create date: 2011/02/10
-- Description: Deletes recors from table [dbo].[TestTable]
-- =======================================================
CREATE PROCEDURE [dbo].[usp_CRUD_TestTable_D]
@ID [int]
AS
BEGIN
SET NOCOUNT ON;
DELETE FROM [dbo].[TestTable]
WHERE
[ID] = @ID
END
GO
--Drop existing INSERT CRUD Procedure
IF (EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID('[dbo].[usp_CRUD_TestTable_I]') AND type = 'P'))
DROP PROCEDURE [dbo].[usp_CRUD_TestTable_I]
GO
-- =======================================================
-- Author: [PAVEL-PCPavel]
-- Create date: 2011/02/10
-- Description: Deletes recors from table [dbo].[TestTable]
-- =======================================================
CREATE PROCEDURE [dbo].[usp_CRUD_TestTable_I]
@Name [varchar](10),
@Price [money],
@Quantity [decimal](5, 2)
AS
BEGIN
SET NOCOUNT ON;
INSERT INTO [dbo].[TestTable] (
[Name]
,[Price]
,[Quantity]
)
OUTPUT
inserted.[ID]
,inserted.[TotalPrice]
SELECT
@Name
,@Price
,@Quantity
END
GO
Like this:
Like Loading...