Add support for MS SQL Server in the DB Labs

git-svn-id: http://webgoat.googlecode.com/svn/trunk@240 4033779f-a91e-0410-96ef-6bf7bf53c507
This commit is contained in:
rogan.dawes 2008-01-10 10:13:52 +00:00
parent 900a222316
commit 36b32849df
9 changed files with 335 additions and 4 deletions

View File

@ -143,8 +143,10 @@ public class DBCrossSiteScripting extends GoatHillsFinancial
else if (STAGE2.equals(stage))
{
instructions = "Stage 2: Block Stored XSS using Input Validation.<br>"
+ "Implement a fix in the stored procedure to prevent the stored XSS from being written to the database. "
+ "A sample regluar expression pattern: ^[a-zA-Z0-9,\\. ]{0,80}$ "
+ "Implement a fix in the stored procedure to prevent the stored XSS from being written to the database. ";
if (getWebgoatContext().getDatabaseDriver().contains("jtds"))
instructions += "Use the provided user-defined function RegexMatch to test the data against a pattern. ";
instructions += "A sample regular expression pattern: ^[a-zA-Z0-9,\\. ]{0,80}$ "
+ "Repeat stage 1 as 'Eric' with 'David' as the manager. Verify that 'David' is not affected by the attack.";
}
}

View File

@ -125,7 +125,8 @@ public class UpdateProfile extends DefaultLessonAction
{
s.setMessage("Error updating employee profile");
e.printStackTrace();
if (DBCrossSiteScripting.STAGE2.equals(getStage(s)) && e.getMessage().contains("ORA-06512") &&
if (DBCrossSiteScripting.STAGE2.equals(getStage(s)) &&
(e.getMessage().contains("ORA-06512") || e.getMessage().contains("Illegal characters")) &&
!employee.getAddress1().matches("^[a-zA-Z0-9,\\. ]{0,80}$"))
{
setStageComplete(s, DBCrossSiteScripting.STAGE2);

View File

@ -0,0 +1,17 @@
using System.Data.SqlTypes;
using System.Text.RegularExpressions;
using Microsoft.SqlServer.Server;
public static partial class UserDefinedFunctions
{
public static readonly RegexOptions Options =
RegexOptions.IgnorePatternWhitespace |
RegexOptions.Compiled | RegexOptions.Singleline;
[SqlFunction]
public static SqlBoolean RegexMatch( SqlChars input, SqlString pattern )
{
Regex regex = new Regex( pattern.Value, Options );
return regex.IsMatch( new string( input.Value ) );
}
}

View File

@ -73,6 +73,19 @@ END;
3. Apply a table column constraint
ALTER TABLE EMPLOYEE
ADD CONSTRAINT address1_ck CHECK (REGEXP_LIKE(address1, '^[a-zA-Z0-9,\. ]{0,80}$'));
FOR SQL SERVER, the following process is required:
Compile the C# RegexMatch user defined class routine to a DLL:
C:> c:\windows\Microsoft.NET\Framework\v2.0.50727\csc.exe /t:library RegexMatch.cs
C:> copy RegexMatch.dll C:\TEMP\
execute the following script as the SA user, using SQuirreL SQL client:
sqlserver.sql
*/
public class UpdateProfile_i extends UpdateProfile

View File

@ -0,0 +1,58 @@
IF EXISTS
(
SELECT 1
FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_NAME = 'UPDATE_EMPLOYEE'
AND ROUTINE_SCHEMA = 'webgoat_guest'
AND ROUTINE_TYPE = 'PROCEDURE'
)
BEGIN
DROP PROCEDURE webgoat_guest.UPDATE_EMPLOYEE
END
GO
CREATE PROCEDURE webgoat_guest.UPDATE_EMPLOYEE
@v_userid INT,
@v_first_name VARCHAR(20),
@v_last_name VARCHAR(20),
@v_ssn VARCHAR(12),
@v_title VARCHAR(20),
@v_phone VARCHAR(13),
@v_address1 VARCHAR(80),
@v_address2 VARCHAR(80),
@v_manager INT,
@v_start_date CHAR(8),
@v_salary INT,
@v_ccn VARCHAR(30),
@v_ccn_limit INT,
@v_disciplined_date CHAR(8),
@v_disciplined_notes VARCHAR(60),
@v_personal_description VARCHAR(60)
AS
IF [webgoat_guest].RegexMatch(@v_address1, N'^[a-zA-Z0-9,\. ]{0,80}$') = 0
BEGIN
RAISERROR('Illegal characters in address1', 11, 1)
RETURN
END
UPDATE EMPLOYEE
SET
first_name = @v_first_name,
last_name = @v_last_name,
ssn = @v_ssn,
title = @v_title,
phone = @v_phone,
address1 = @v_address1,
address2 = @v_address2,
manager = @v_manager,
start_date = @v_Start_date,
salary = @v_salary,
ccn = @v_ccn,
ccn_limit = @v_ccn_limit,
disciplined_date = @v_disciplined_date,
disciplined_notes = @v_disciplined_notes,
personal_description = @v_personal_description
WHERE
userid = @v_userid;
GO

View File

@ -3,9 +3,10 @@ package org.owasp.webgoat.lessons.instructor.DBSQLInjection;
/*
* The solution is to choose Neville's userid, and enter a password like:
* ' OR '1'='1
* Modify the Stored procedure LOGIN_EMPLOYEE to use fixed statements or bind variables
* Modify the Stored function LOGIN_EMPLOYEE to use fixed statements or bind variables
*
*
* For ORACLE:
CREATE OR REPLACE FUNCTION WEBGOAT_guest.EMPLOYEE_LOGIN(v_id NUMBER, v_password VARCHAR) RETURN NUMBER AS
cnt NUMBER;
BEGIN
@ -27,4 +28,17 @@ BEGIN
END;
/
* For SQL SERVER
CREATE FUNCTION webgoat_guest.EMPLOYEE_LOGIN (
@v_id INT,
@v_password VARCHAR(100)
) RETURNS INTEGER
AS
BEGIN
DECLARE @count int
SELECT @count = COUNT(*) FROM EMPLOYEE WHERE USERID = @v_id AND PASSWORD = @v_password;
return @count
END
*/

View File

@ -0,0 +1,226 @@
EXEC sp_configure 'clr enabled', 1
GO
RECONFIGURE
GO
USE master;
go
DROP LOGIN webgoat_guest;
go
DROP database webgoat;
go
CREATE database webgoat;
go
USE webgoat;
go
CREATE SCHEMA webgoat_guest;
go
CREATE LOGIN webgoat_guest with password = '_webgoat';
go
CREATE USER webgoat_guest with default_schema = webgoat_guest;
go
GRANT CONTROL TO webgoat_guest;
go
CREATE TABLE WEBGOAT_guest.EMPLOYEE (
userid INT NOT NULL PRIMARY KEY,
first_name VARCHAR(20),
last_name VARCHAR(20),
ssn VARCHAR(12),
password VARCHAR(10),
title VARCHAR(20),
phone VARCHAR(13),
address1 VARCHAR(80),
address2 VARCHAR(80),
manager INT,
start_date CHAR(8),
salary INT,
ccn VARCHAR(30),
ccn_limit INT,
disciplined_date CHAR(8),
disciplined_notes VARCHAR(60),
personal_description VARCHAR(60)
);
go
IF EXISTS
(
SELECT 1
FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_NAME = 'UPDATE_EMPLOYEE'
AND ROUTINE_SCHEMA = 'webgoat_guest'
AND ROUTINE_TYPE = 'PROCEDURE'
)
BEGIN
DROP PROCEDURE webgoat_guest.UPDATE_EMPLOYEE
DROP PROCEDURE webgoat_guest.UPDATE_EMPLOYEE_BACKUP
END
GO
CREATE PROCEDURE webgoat_guest.UPDATE_EMPLOYEE
@v_userid INT,
@v_first_name VARCHAR(20),
@v_last_name VARCHAR(20),
@v_ssn VARCHAR(12),
@v_title VARCHAR(20),
@v_phone VARCHAR(13),
@v_address1 VARCHAR(80),
@v_address2 VARCHAR(80),
@v_manager INT,
@v_start_date CHAR(8),
@v_salary INT,
@v_ccn VARCHAR(30),
@v_ccn_limit INT,
@v_disciplined_date CHAR(8),
@v_disciplined_notes VARCHAR(60),
@v_personal_description VARCHAR(60)
AS
UPDATE EMPLOYEE
SET
first_name = @v_first_name,
last_name = @v_last_name,
ssn = @v_ssn,
title = @v_title,
phone = @v_phone,
address1 = @v_address1,
address2 = @v_address2,
manager = @v_manager,
start_date = @v_Start_date,
salary = @v_salary,
ccn = @v_ccn,
ccn_limit = @v_ccn_limit,
disciplined_date = @v_disciplined_date,
disciplined_notes = @v_disciplined_notes,
personal_description = @v_personal_description
WHERE
userid = @v_userid;
go
CREATE PROCEDURE webgoat_guest.UPDATE_EMPLOYEE_BACKUP
@v_userid INT,
@v_first_name VARCHAR(20),
@v_last_name VARCHAR(20),
@v_ssn VARCHAR(12),
@v_title VARCHAR(20),
@v_phone VARCHAR(13),
@v_address1 VARCHAR(80),
@v_address2 VARCHAR(80),
@v_manager INT,
@v_start_date CHAR(8),
@v_salary INT,
@v_ccn VARCHAR(30),
@v_ccn_limit INT,
@v_disciplined_date CHAR(8),
@v_disciplined_notes VARCHAR(60),
@v_personal_description VARCHAR(60)
AS
UPDATE EMPLOYEE
SET
first_name = @v_first_name,
last_name = @v_last_name,
ssn = @v_ssn,
title = @v_title,
phone = @v_phone,
address1 = @v_address1,
address2 = @v_address2,
manager = @v_manager,
start_date = @v_Start_date,
salary = @v_salary,
ccn = @v_ccn,
ccn_limit = @v_ccn_limit,
disciplined_date = @v_disciplined_date,
disciplined_notes = @v_disciplined_notes,
personal_description = @v_personal_description
WHERE
userid = @v_userid;
go
IF EXISTS
(
SELECT 1
FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_NAME = 'EMPLOYEE_LOGIN'
AND ROUTINE_SCHEMA = 'webgoat_guest'
AND ROUTINE_TYPE = 'FUNCTION'
)
BEGIN
DROP FUNCTION webgoat_guest.EMPLOYEE_LOGIN
DROP FUNCTION webgoat_guest.EMPLOYEE_LOGIN_BACKUP
END
GO
CREATE FUNCTION webgoat_guest.EMPLOYEE_LOGIN (
@v_id INT,
@v_password VARCHAR(100)
) RETURNS INTEGER
AS
BEGIN
DECLARE @sql nvarchar(4000), @count int
SELECT @sql = N'SELECT @cnt = COUNT(*) FROM EMPLOYEE WHERE USERID = ' + convert(varchar(10),@v_id) + N' AND PASSWORD = ''' + @v_password + N'''';
EXEC sp_executesql @sql, N'@cnt int OUTPUT', @cnt = @count OUTPUT
return @count
END
GO
CREATE FUNCTION webgoat_guest.EMPLOYEE_LOGIN_BACKUP (
@v_id INT,
@v_password VARCHAR(100)
) RETURNS INTEGER
AS
BEGIN
DECLARE @sql nvarchar(4000), @count int
SELECT @sql = N'SELECT @cnt = COUNT(*) FROM EMPLOYEE WHERE USERID = ' + convert(varchar(10),@v_id) + N' AND PASSWORD = ''' + @v_password + N'''';
EXEC sp_executesql @sql, N'@cnt int OUTPUT', @cnt = @count OUTPUT
return @count
END
GO
IF EXISTS
(
SELECT 1
FROM INFORMATION_SCHEMA.ROUTINES
WHERE ROUTINE_NAME = 'RegexMatch'
AND ROUTINE_SCHEMA = 'webgoat_guest'
AND ROUTINE_TYPE = 'FUNCTION'
)
BEGIN
DROP FUNCTION webgoat_guest.RegexMatch
END
GO
IF EXISTS (SELECT name FROM sys.assemblies WHERE name = N'RegexMatch')
DROP ASSEMBLY RegexMatch;
GO
CREATE ASSEMBLY RegexMatch FROM 'c:\AspectClassCD\WebGoat\RegexMatch.dll' WITH PERMISSION_SET = SAFE;
GO
CREATE FUNCTION webgoat_guest.RegexMatch (
@input NVARCHAR(MAX),
@pattern NVARCHAR(MAX)
) RETURNS BIT
AS EXTERNAL NAME RegexMatch.[UserDefinedFunctions].RegexMatch;
GO