GuardRails

GuardRails

  • Languages iconEnglish
    • 中文

›Dotnet

Overview

  • Introduction
  • What is GuardRails
  • Getting started
  • Findings
  • Vulnerabilities
  • Configuration
  • Custom Engines
  • False Positives
  • Enforce Passing Checks
  • Build Status on Pull Requests
  • FAQ
  • Pricing
  • Glossary
  • Tools & Licenses

API

  • Usage Guide
  • Endpoints

Vulnerabilities

  • Introduction
  • General

    • Overview
    • Hard-Coded Secrets

    Apex

    • Overview
    • Insecure Access Control
    • Insecure Network Communication
    • Insecure Processing of Data
    • Insecure Use of Cryptography
    • Insecure Use of Language/Framework API
    • Insecure Use of SQL Queries

    C/C++

    • Overview
    • Insecure Access Control
    • Insecure File Management
    • Insecure Processing of Data
    • Insecure Use of Cryptography
    • Insecure Use of Dangerous Function

    Dotnet

    • Overview
    • Insecure Access Control
    • Insecure Configuration
    • Insecure File Management
    • Insecure Processing of Data
    • Insecure Use of Cryptography
    • Insecure Use of Dangerous Function
    • Insecure Use of SQL Queries
    • Using Vulnerable Libraries

    Elixir

    • Overview
    • Insecure Configuration
    • Insecure File Management
    • Insecure Processing of Data
    • Insecure Network Communication
    • Insecure Use of Dangerous Function
    • Insecure Use of Language/Framework API
    • Insecure Use of SQL Queries
    • Using Vulnerable Libraries

    Go

    • Overview
    • Insecure File Management
    • Insecure Network Communication
    • Insecure Processing of Data
    • Insecure Use of Cryptography
    • Insecure Use of Dangerous Function
    • Insecure Use of SQL Queries
    • Using Vulnerable Libraries

    Java

    • Overview
    • Using Vulnerable Libraries
    • Insecure Use of SQL Queries
    • Insecure Use of Dangerous Function
    • Insecure Use of Regular Expressions
    • Insecure Authentication
    • Insecure Configuration
    • Insecure File Management
    • Insecure Use of Cryptography
    • Insecure Use of Language/Framework API
    • Insecure Processing of Data
    • Insecure Network Communication

    Javascript/TypeScript

    • Overview
    • Insecure Authentication
    • Insecure Processing of Data
    • Insecure Use of SQL Queries
    • Insecure Use of Regular Expressions
    • Insecure Use of Language/Framework API
    • Insecure Use of Dangerous Function
    • Using Vulnerable Libraries

    Kubernetes

    • Overview
    • Insecure Access Control
    • Insecure Configuration
    • Insecure Network Communication

    PHP

    • Overview
    • Insecure Configuration
    • Insecure File Management
    • Insecure Network Communication
    • Insecure Processing of Data
    • Insecure Use of Dangerous Function
    • Insecure Use of Language/Framework API
    • Insecure Use of Regular Expressions
    • Insecure Use of SQL Queries
    • Using Vulnerable Libraries

    Python

    • Overview
    • Insecure Configuration
    • Insecure Use of Cryptography
    • Insecure Network Communication
    • Insecure Processing of Data
    • Insecure Use of Dangerous Function
    • Insecure Use of SQL Queries
    • Using Vulnerable Libraries

    Ruby

    • Overview
    • Insecure Access Control
    • Insecure Configuration
    • Insecure File Management
    • Insecure Network Communication
    • Insecure Processing of Data
    • Insecure Use of Dangerous Function
    • Insecure Use of Language/Framework API
    • Insecure Use of Regular Expressions
    • Insecure Use of SQL Queries
    • Using Vulnerable Libraries

    Rust

    • Overview
    • Using Vulnerable Libraries

    Solidity

    • Overview
    • Insecure Integer Arithmetic
    • Insecure Use of Low-Level Call
    • Reliance on Insecure Random Numbers
    • State Change After External Call
    • Transaction Order Dependence
    • Unprotected Critical Function
    • Use of Insecure Function
    • Dependence on Predictable Environment Variables
    • Write to Arbitrary Storage Location
    • Call to Untrusted Contract

    Terraform

    • Overview
    • Hard-Coded Secrets
    • Insecure Access Control
    • Insecure Configuration
    • Insecure Network Communication
    • Insecure Use of Cryptography

Insecure Use of SQL Queries

Why is this important?

SQL injections are dangerous because they can be easily identified by attackers. Hackers can use SQL injections to read from and sometimes even write to your database. SQL injections are very common and have been the cause of many high-profile breaches.

Check out this video for a high-level explanation:

SQL Injection Explanation Video

References:

  • WASC-19: SQL Injection
  • OWASP: Query Parameterization Cheat Sheet
  • SQL Injection Prevention Cheat Sheet
  • CAPEC-66: SQL Injection
  • Common Weakness Enumeration (CWE-89)

This is a biggie, read below to find out how to fix it.

Fixing Insecure Use of SQL Queries

To help protect against SQL statement exploits, never create SQL queries using string concatenation. Instead, use a parameterized query and assign user input to parameter objects.

Option A: LINQ based SQL Injection

References:

  • LINQ: How to Query for Information

Follow these steps:

  1. Go through the issues that GuardRails identified in the PR.
  2. Look for insecure patterns like this:
db.ExecuteQuery(@"SELECT name FROM dbo.Users WHERE UserId = " + inputId + " AND group = 5");

// or:
var query = "SELECT name FROM dbo.Users WHERE UserId = " + userId + " AND group = 5";
var id = context.ExecuteQuery<IEnumerable<string>>(query).SingleOrDefault();
  1. Replace it with the following:
var query = from user in db.Users
where user.UserId == inputId
select user.name;

// or:
var query = "SELECT name FROM dbo.Users WHERE UserId = {0} AND group = 5";
var id = context.ExecuteQuery<IEnumerable<string>>(query, userId).SingleOrDefault();
  1. Test it, ship it 🚢 and relax 🌴

Option B: WebControls based SQL Injection

References:

  • MSDN: Using Parameters with the SqlDataSource Control
  • MSDN: Script Exploits Overview
  • MSDN: Filtering Event

Follow these steps:

  1. Go through the issues that GuardRails identified in the PR.
  2. Look for insecure patterns like this:
"Select * From Customers where CustomerName = " & txtCustomerName.Value
  1. By default, the SqlDataSource control uses the System.Data.SqlClient data provider to work with SQL Server as the data source. The System.Data.SqlClient provider supports named parameters as placeholders, as shown in the following example:
<asp:sqlDataSource ID="EmployeeDetailsSqlDataSource" 
  SelectCommand="SELECT EmployeeID, LastName, FirstName FROM Employees WHERE EmployeeID = @EmpID"

  InsertCommand="INSERT INTO Employees(LastName, FirstName) VALUES (@LastName, @FirstName); 
                SELECT @EmpID = SCOPE_IDENTITY()"
  UpdateCommand="UPDATE Employees SET [email protected], [email protected] 
                  WHERE [email protected]"
  DeleteCommand="DELETE Employees WHERE [email protected]"

  ConnectionString="<%$ ConnectionStrings:NorthwindConnection %>"
  OnInserted="EmployeeDetailsSqlDataSource_OnInserted"
  RunAt="server">

  <SelectParameters>
    <asp:Parameter Name="EmpID" Type="Int32" DefaultValue="0" />
  </SelectParameters>

  <InsertParameters>
    <asp:Parameter Name="EmpID" Direction="Output" Type="Int32" DefaultValue="0" />
  </InsertParameters>
</asp:sqlDataSource>

Or if you are connecting to an OLE DB or ODBC data source, you can configure the SqlDataSource control to use the System.Data.OleDb or System.Data.Odbc provider to work with your data source, respectively. The System.Data.OleDb and System.Data.Odbc providers support only positional parameters identified by the “?” character, as shown in the following example:

<asp:SqlDataSource ID="EmployeeDetailsSqlDataSource" 
  SelectCommand="SELECT EmployeeID, LastName, FirstName, Address, City, Region, PostalCode
                FROM Employees WHERE EmployeeID = ?"

  InsertCommand="INSERT INTO Employees(LastName, FirstName, Address, City, Region, PostalCode)
                VALUES (?, ?, ?, ?, ?, ?); 
                SELECT @EmpID = SCOPE_IDENTITY()"

  UpdateCommand="UPDATE Employees SET LastName=?, FirstName=?, Address=?,
                  City=?, Region=?, PostalCode=?
                WHERE EmployeeID=?"
  1. Test it, ship it 🚢 and relax 🌴

Option C: OLE DB based SQL Injection

References:

  • OleDbCommand Documentation

Follow these steps:

  1. Go through the issues that GuardRails identified in the PR.
  2. Look for insecure patterns like this:
string queryString = "SELECT OrderID, CustomerID FROM Orders WHERE OrderId = " + userInput;

using (var connection = new OleDbConnection(connectionString))
{
    OleDbCommand command = new OleDbCommand(queryString, connection);
    connection.Open();
    OleDbDataReader reader = command.ExecuteReader();
}
  1. Replace it with the following:
string queryString = "SELECT OrderID, CustomerID FROM Orders WHERE OrderId = ?";

using (var connection = new OleDbConnection(connectionString))
{
    OleDbCommand command = new OleDbCommand(queryString, connection);
    command.Parameters.Add("@p1", OleDbType.Integer).Value = userInput;
    connection.Open();
    OleDbDataReader reader = command.ExecuteReader();
}
  1. Test it, ship it 🚢 and relax 🌴

Option D: ODBC based SQL Injection

References:

  • OdbcCommand Documentation

Follow these steps:

  1. Go through the issues that GuardRails identified in the PR.
  2. Look for insecure patterns like this:
var command = new OdbcCommand("SELECT * FROM [user] WHERE id = " + userInput, connection);
OdbcDataReader reader = command.ExecuteReader();
  1. Replace it with the following:
var command = new OdbcCommand("SELECT * FROM [user] WHERE id = ?", connection);
command.Parameters.Add("@id", OdbcType.Int).Value = 4;
OdbcDataReader reader = command.ExecuteReader();
  1. Test it, ship it 🚢 and relax 🌴

Option E: MsSQL Data Provider based SQL Injection

References:

  • SQLCommand Class Documentation

Follow these steps:

  1. Go through the issues that GuardRails identified in the PR.
  2. Look for insecure patterns like this:
var cmd = new SqlCommand("SELECT * FROM Users WHERE username = '" + username + "' and role='user'");
  1. Replace it with the following:
var cmd = new SqlCommand("SELECT * FROM Users WHERE username = @username and role='user'");
cmd.Parameters.AddWithValue("username", username);
  1. Test it, ship it 🚢 and relax 🌴

Option F: Entity Framework based SQL Injection

References:

  • Entity Framework Documentation

Follow these steps:

  1. Go through the issues that GuardRails identified in the PR.
  2. Look for insecure patterns like this:
var cmd = "SELECT * FROM Users WHERE username = '" + input + "' and role='user'";
ctx.Database.ExecuteSqlCommand(
  cmd);
  1. Replace it with the following:
var cmd = "SELECT * FROM Users WHERE username = @username and role='user'";
ctx.Database.ExecuteSqlCommand(
    cmd,
    new SqlParameter("@username", input));
  1. Test it, ship it 🚢 and relax 🌴

Option G: EnterpriseLibrary.Data based SQL Injection

References:

  • Microsoft.Practices.EnterpriseLibrary.Data.Sql Namespace

Follow these steps:

  1. Go through the issues that GuardRails identified in the PR.
  2. Look for insecure patterns like this:
db.ExecuteDataSet(CommandType.Text, "SELECT * FROM Users WHERE username = '" + input + "' and role='user'");
  1. Replace it with the following:
DbCommand cmd = db.GetSqlStringCommand("SELECT * FROM Users WHERE username = @username and role='user'");
db.AddInParameter(cmd, "@username", DbType.String, input);
db.ExecuteDataSet(cmd);
  1. Test it, ship it 🚢 and relax 🌴

Option H: nHibernate based SQL Injection

References:

  • nHibernate Manual - Querying Data

Follow these steps:

  1. Go through the issues that GuardRails identified in the PR.
  2. Look for insecure patterns like this:
session.CreateSQLQuery("SELECT * FROM users WHERE username = '" + username + "';");
  1. Replace it with the following:
session.CreateSQLQuery("SELECT * FROM users WHERE username = :username;").SetParameter("username", username);
  1. Test it, ship it 🚢 and relax 🌴

Option H: Cassandra based CQL Injection

References:

  • Datastax Documentation - Named parameters

Follow these steps:

  1. Go through the issues that GuardRails identified in the PR.
  2. Look for insecure patterns like this:
session.Execute("SELECT * FROM users WHERE username = '" + username + "';");
  1. Replace it with the following:
var preparedStatement = session.Prepare("SELECT * FROM users WHERE username = :username");

var boundStatement = preparedStatement.Bind(new
{
  username = username
});

session.Execute(boundStatement);
  1. Test it, ship it 🚢 and relax 🌴

Option I: Npgsql based SQL Injection

References:

  • Npgsql Documentation - Npgsql Basic Usage

Follow these steps:

  1. Go through the issues that GuardRails identified in the PR.
  2. Look for insecure patterns like this:
var cmd = new NpgsqlCommand("SELECT * FROM users WHERE username = '" +  username + "';");
  1. Replace it with the following:
var cmd = new NpgsqlCommand("SELECT * FROM users WHERE username = :username;");
cmd.Parameters.AddWithValue("username", username);
  1. Test it, ship it 🚢 and relax 🌴
← Insecure Use of Dangerous FunctionUsing Vulnerable Libraries →
  • Why is this important?
  • Fixing Insecure Use of SQL Queries
    • Option A: LINQ based SQL Injection
    • Option B: WebControls based SQL Injection
    • Option C: OLE DB based SQL Injection
    • Option D: ODBC based SQL Injection
    • Option E: MsSQL Data Provider based SQL Injection
    • Option F: Entity Framework based SQL Injection
    • Option G: EnterpriseLibrary.Data based SQL Injection
    • Option H: nHibernate based SQL Injection
    • Option H: Cassandra based CQL Injection
    • Option I: Npgsql based SQL Injection
  • Status
  • Help
  • Security
  • Terms
  • Privacy

© 2021 GuardRails