Secure Code Warrior_.Net Core 資安練習_SQL Injection防範(二)

 

一個有漏洞的程式碼範例


  1
  2
  3
  4
  5
  6
  7
  8
  9
 10
 11
 12
 13
 14
 15
 16
 17
 18
 19
 20
 21
 22
 23
 24
 25
 26
 27
 28
 29
 30
 31
 32
 33
 34
 35
 36
 37
 38
 39
 40
 41
 42
 43
 44
 45
 46
 47
 48
 49
 50
 51
 52
 53
 54
 55
 56
 57
 58
 59
 60
 61
 62
 63
 64
 65
 66
 67
 68
 69
 70
 71
 72
 73
 74
 75
 76
 77
 78
 79
 80
 81
 82
 83
 84
 85
 86
 87
 88
 89
 90
 91
 92
 93
 94
 95
 96
 97
 98
 99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
using CoreChallenge.Models;
using System;
using System.Collections.Generic;
using System.Data;
using System.Data.SqlClient;
using System.IO;
using System.Reflection;
using System.Security.Cryptography;
namespace CoreChallenge.Db
{
    public class DbOperations : IDbOperations
    {
        const string DbName = "CoreChallenge";

        string ConnectionString { get; }
        string DbFileName { get; }

        SqlConnection Connection { get; set; }

        public DbOperations(string connectionString)
        {
            DbFileName = Path.Combine(Path.GetDirectoryName(Assembly.GetExecutingAssembly().Location), $"{DbName}.mdf");
            ConnectionString = string.Format(connectionString, DbName);

            if (File.Exists(DbFileName))
                OpenConnection();
            else
                CreateDb(string.Format(connectionString, "master"));
        }

        void OpenConnection()
        {
            Connection = new SqlConnection(ConnectionString);

            Connection.Open();
        }

        public void CreateDb(string connectionString)
        {
            if (File.Exists(DbFileName))
                File.Delete(DbFileName);

            using (var connection = new SqlConnection(connectionString))
            {
                connection.Open();

                DetachDatabase(connection);

                using (SqlCommand sqlCommand = connection.CreateCommand())
                {
                    sqlCommand.CommandText = $"CREATE DATABASE {DbName} ON (NAME = N'{DbName}', FILENAME = '{DbFileName}')";

                    sqlCommand.ExecuteNonQuery();
                }

                connection.Close();
            }

            Seed();
        }

        static void DetachDatabase(SqlConnection sqlConnection)
        {
            using (var cmd = sqlConnection.CreateCommand())
            {
                cmd.CommandText = String.Format("exec sp_detach_db '{0}'", DbName);

                cmd.ExecuteNonQuery();
            }
        }

        void Seed()
        {
            OpenConnection();
            CreateTables();
            FillData();
        }

        void FillData()
        {
            AddOrder(new Order { UserName = "John Smith", UserPhone = "Test 1", UserAddress = "Test 2", OrderDate = DateTime.Now.AddDays(-1) });
            AddOrder(new Order { UserName = "Juan Carlos", UserPhone = "Test 4", UserAddress = "Test 5", OrderDate = DateTime.Now.AddDays(-2) });
            AddOrder(new Order { UserName = "Ricardo Jones", UserPhone = "Test 7", UserAddress = "Test 8", OrderDate = DateTime.Now });
        }

        void CreateTables()
        {
            var sql = @"
                CREATE TABLE [dbo].[Order](
	                [Id] [uniqueidentifier] NOT NULL,
	                [UserName] [nvarchar](max) NULL,
	                [UserPhone] [nvarchar](max) NULL,
	                [UserAddress] [nvarchar](max) NULL,
	                [OrderDate] [datetime] NULL,
                    [Cookie] [nvarchar](max) NULL,
                 CONSTRAINT [PK_Order] PRIMARY KEY CLUSTERED 
                (
	                [Id] ASC
                )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
                ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
            ";

            using (SqlCommand sqlCommand = Connection.CreateCommand())
            {
                sqlCommand.CommandText = sql;

                ExecuteTransaction(sqlCommand);
            }
        }

        public string AddOrder(Order order)
        {
            var sql = @"INSERT INTO [dbo].[Order] ([Id],[UserName],[UserPhone],[UserAddress],[OrderDate],[Cookie])VALUES(@Id,@UserName,@UserPhone,@UserAddress,@OrderDate,@Cookie)";

            Guid id = Guid.NewGuid();
            string cookie = order.OrderDate.ToString("yyyyMMddHHmmss") + GenerateSecureRandom(128);

            using (SqlCommand sqlCommand = Connection.CreateCommand())
            {
                sqlCommand.CommandText = sql;

                sqlCommand.Parameters.AddWithValue("@Id", id);
                sqlCommand.Parameters.AddWithValue("@UserName", order.UserName);
                sqlCommand.Parameters.AddWithValue("@UserPhone", order.UserPhone);
                sqlCommand.Parameters.AddWithValue("@UserAddress", order.UserAddress);
                sqlCommand.Parameters.AddWithValue("@OrderDate", order.OrderDate);
                sqlCommand.Parameters.AddWithValue("@Cookie", cookie);

                ExecuteTransaction(sqlCommand);
            }

            return cookie;
        }

        void ExecuteTransaction(SqlCommand sqlCommand)
        {
            using (SqlTransaction transaction = Connection.BeginTransaction())
            {
                sqlCommand.Transaction = transaction;

                try
                {
                    sqlCommand.ExecuteNonQuery();

                    transaction.Commit();
                }
                catch (Exception ex)
                {
                    transaction.Rollback();
                    throw ex;
                }
            }
        }

        public void Dispose()
        {
            if (Connection.State != ConnectionState.Closed)
            {
                Connection.Close();
            }

            Connection.Dispose();
        }

        public List<Order> GetPreviousOrders()
        {
            var orders = new List<Order>();

            var sql = "select top 5 UserName, UserPhone, UserAddress, OrderDate from [dbo].[Order] order by OrderDate desc";

            using (SqlCommand sqlCommand = Connection.CreateCommand())
            {
                sqlCommand.CommandText = sql;

                using (SqlDataReader sqlDataReader = sqlCommand.ExecuteReader())
                {
                    while (sqlDataReader.Read())
                    {
                        var order = new Order
                        {
                            UserName = sqlDataReader["UserName"].ToString(),
                            OrderDate = Convert.ToDateTime(sqlDataReader["OrderDate"])
                        };

                        orders.Add(order);
                    }
                }
            }

            return orders;
        }

        public Order GetOrderByCookie(string cookie)
        {
            var sql = "select top 1 UserName, UserPhone, UserAddress, OrderDate from [dbo].[Order] where Cookie = @Cookie";

            using (SqlCommand sqlCommand = Connection.CreateCommand())
            {
                sqlCommand.CommandText = sql.Replace("@Cookie", cookie);

                using (SqlDataReader sqlDataReader = sqlCommand.ExecuteReader())
                {
                    if (sqlDataReader.Read())
                    {
                        var order = new Order
                        {
                            UserName = sqlDataReader["UserName"].ToString(),
                            OrderDate = Convert.ToDateTime(sqlDataReader["OrderDate"]),
                            UserAddress = sqlDataReader["UserAddress"].ToString(),
                            UserPhone = sqlDataReader["UserPhone"].ToString()
                        };

                        return order;
                    }
                }
            }

            return null;
        }

        public List<Order> GetAllOrders()
        {
            var orders = new List<Order>();

            var sql = "select UserName, UserPhone, UserAddress, OrderDate from [dbo].[Order] order by OrderDate desc";

            using (SqlCommand sqlCommand = Connection.CreateCommand())
            {
                sqlCommand.CommandText = sql;

                using (SqlDataReader sqlDataReader = sqlCommand.ExecuteReader())
                {
                    while (sqlDataReader.Read())
                    {
                        var order = new Order
                        {
                            UserName = sqlDataReader["UserName"].ToString(),
                            OrderDate = Convert.ToDateTime(sqlDataReader["OrderDate"]),
                            UserAddress = sqlDataReader["UserAddress"].ToString(),
                            UserPhone = sqlDataReader["UserPhone"].ToString()
                        };

                        orders.Add(order);
                    }
                }
            }

            return orders;
        }

        string GenerateSecureRandom(int length)
        {
            RNGCryptoServiceProvider rngCryptoServiceProvider = new RNGCryptoServiceProvider();
            byte[] randomBytes = new byte[length];
            rngCryptoServiceProvider.GetBytes(randomBytes);
            return Convert.ToBase64String(randomBytes);
        }
    }
}







解決方案1-htmlencode

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
        public Order GetOrderByCookie(string cookie)
        {
            var sql = "select top 1 UserName, UserPhone, UserAddress, OrderDate from [dbo].[Order] where Cookie = @Cookie";

            using (SqlCommand sqlCommand = Connection.CreateCommand())
            {
                sqlCommand.CommandText = sql.Replace("@Cookie", HttpUtility.HtmlEncode(cookie));

                using (SqlDataReader sqlDataReader = sqlCommand.ExecuteReader())
                {
                    if (sqlDataReader.Read())
                    {
                        var order = new Order
                        {
                            UserName = sqlDataReader["UserName"].ToString(),
                            OrderDate = Convert.ToDateTime(sqlDataReader["OrderDate"]),
                            UserAddress = sqlDataReader["UserAddress"].ToString(),
                            UserPhone = sqlDataReader["UserPhone"].ToString()
                        };

                        return order;
                    }
                }
            }

            return null;
        }


解決方案2-黑名單取代


 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
        public Order GetOrderByCookie(string cookie)
        {
            var sql = "select top 1 UserName, UserPhone, UserAddress, OrderDate from [dbo].[Order] where Cookie = @Cookie";

            using (SqlCommand sqlCommand = Connection.CreateCommand())
            {
                sqlCommand.CommandText = sql.Replace("@Cookie", RemoveSqlSpecialCharacters(cookie));

                using (SqlDataReader sqlDataReader = sqlCommand.ExecuteReader())
                {
                    if (sqlDataReader.Read())
                    {
                        var order = new Order
                        {
                            UserName = sqlDataReader["UserName"].ToString(),
                            OrderDate = Convert.ToDateTime(sqlDataReader["OrderDate"]),
                            UserAddress = sqlDataReader["UserAddress"].ToString(),
                            UserPhone = sqlDataReader["UserPhone"].ToString()
                        };

                        return order;
                    }
                }
            }

            return null;
        }

        string RemoveSqlSpecialCharacters(string str)
        {
            var specialCharacters = new char[]
            {
                ' ', '\'', '"', '(', ')', '[', ']'
            };

            string resultStr = str;

            foreach (char character in specialCharacters)
                resultStr = resultStr.Replace(character.ToString(), string.Empty);

            return resultStr;
        }



(O)解決方案3-參數化串入

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
        public Order GetOrderByCookie(string cookie)
        {
            var sql = "select top 1 UserName, UserPhone, UserAddress, OrderDate from [dbo].[Order] where Cookie = @Cookie";

            using (SqlCommand sqlCommand = Connection.CreateCommand())
            {
                sqlCommand.CommandText = sql;

                sqlCommand.Parameters.AddWithValue("@Cookie", cookie);

                using (SqlDataReader sqlDataReader = sqlCommand.ExecuteReader())
                {
                    if (sqlDataReader.Read())
                    {
                        var order = new Order
                        {
                            UserName = sqlDataReader["UserName"].ToString(),
                            OrderDate = Convert.ToDateTime(sqlDataReader["OrderDate"]),
                            UserAddress = sqlDataReader["UserAddress"].ToString(),
                            UserPhone = sqlDataReader["UserPhone"].ToString()
                        };

                        return order;
                    }
                }
            }

            return null;
        }







留言

這個網誌中的熱門文章

何謂淨重(Net Weight)、皮重(Tare Weight)與毛重(Gross Weight)

Architecture(架構) 和 Framework(框架) 有何不同?_軟體設計前的事前規劃的藍圖概念

經得起原始碼資安弱點掃描的程式設計習慣培養(五)_Missing HSTS Header