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
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
|
/*
* Copyright (c) Contributors, http://opensimulator.org/
* See CONTRIBUTORS.TXT for a full list of copyright holders.
*
* Redistribution and use in source and binary forms, with or without
* modification, are permitted provided that the following conditions are met:
* * Redistributions of source code must retain the above copyright
* notice, this list of conditions and the following disclaimer.
* * Redistributions in binary form must reproduce the above copyright
* notice, this list of conditions and the following disclaimer in the
* documentation and/or other materials provided with the distribution.
* * Neither the name of the OpenSimulator Project nor the
* names of its contributors may be used to endorse or promote products
* derived from this software without specific prior written permission.
*
* THIS SOFTWARE IS PROVIDED BY THE DEVELOPERS ``AS IS'' AND ANY
* EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED
* WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE
* DISCLAIMED. IN NO EVENT SHALL THE CONTRIBUTORS BE LIABLE FOR ANY
* DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES
* (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES;
* LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND
* ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT
* (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS
* SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
*/
using System;
using System.Collections.Generic;
using System.Data;
using System.Reflection;
using log4net;
using OpenMetaverse;
using OpenSim.Framework;
using OpenSim.Region.Framework.Interfaces;
using System.Text;
using Npgsql;
namespace OpenSim.Data.PGSQL
{
public class PGSQLGenericTableHandler<T> : PGSqlFramework where T : class, new()
{
private static readonly ILog m_log =
LogManager.GetLogger(MethodBase.GetCurrentMethod().DeclaringType);
protected string m_ConnectionString;
protected PGSQLManager m_database; //used for parameter type translation
protected Dictionary<string, FieldInfo> m_Fields =
new Dictionary<string, FieldInfo>();
protected Dictionary<string, string> m_FieldTypes = new Dictionary<string, string>();
protected List<string> m_ColumnNames = null;
protected string m_Realm;
protected FieldInfo m_DataField = null;
protected virtual Assembly Assembly
{
get { return GetType().Assembly; }
}
public PGSQLGenericTableHandler(string connectionString,
string realm, string storeName)
: base(connectionString)
{
m_Realm = realm;
m_ConnectionString = connectionString;
if (storeName != String.Empty)
{
using (NpgsqlConnection conn = new NpgsqlConnection(m_ConnectionString))
{
conn.Open();
Migration m = new Migration(conn, GetType().Assembly, storeName);
m.Update();
}
}
m_database = new PGSQLManager(m_ConnectionString);
Type t = typeof(T);
FieldInfo[] fields = t.GetFields(BindingFlags.Public |
BindingFlags.Instance |
BindingFlags.DeclaredOnly);
LoadFieldTypes();
if (fields.Length == 0)
return;
foreach (FieldInfo f in fields)
{
if (f.Name != "Data")
m_Fields[f.Name] = f;
else
m_DataField = f;
}
}
private void LoadFieldTypes()
{
m_FieldTypes = new Dictionary<string, string>();
string query = string.Format(@"select column_name,data_type
from INFORMATION_SCHEMA.COLUMNS
where table_name = lower('{0}');
", m_Realm);
using (NpgsqlConnection conn = new NpgsqlConnection(m_ConnectionString))
using (NpgsqlCommand cmd = new NpgsqlCommand(query, conn))
{
conn.Open();
using (NpgsqlDataReader rdr = cmd.ExecuteReader())
{
while (rdr.Read())
{
// query produces 0 to many rows of single column, so always add the first item in each row
m_FieldTypes.Add((string)rdr[0], (string)rdr[1]);
}
}
}
}
private void CheckColumnNames(NpgsqlDataReader reader)
{
if (m_ColumnNames != null)
return;
m_ColumnNames = new List<string>();
DataTable schemaTable = reader.GetSchemaTable();
foreach (DataRow row in schemaTable.Rows)
{
if (row["ColumnName"] != null &&
(!m_Fields.ContainsKey(row["ColumnName"].ToString())))
m_ColumnNames.Add(row["ColumnName"].ToString());
}
}
// TODO GET CONSTRAINTS FROM POSTGRESQL
private List<string> GetConstraints()
{
List<string> constraints = new List<string>();
string query = string.Format(@"SELECT kcu.column_name
FROM information_schema.table_constraints tc
LEFT JOIN information_schema.key_column_usage kcu
ON tc.constraint_catalog = kcu.constraint_catalog
AND tc.constraint_schema = kcu.constraint_schema
AND tc.constraint_name = kcu.constraint_name
LEFT JOIN information_schema.referential_constraints rc
ON tc.constraint_catalog = rc.constraint_catalog
AND tc.constraint_schema = rc.constraint_schema
AND tc.constraint_name = rc.constraint_name
LEFT JOIN information_schema.constraint_column_usage ccu
ON rc.unique_constraint_catalog = ccu.constraint_catalog
AND rc.unique_constraint_schema = ccu.constraint_schema
AND rc.unique_constraint_name = ccu.constraint_name
where tc.table_name = lower('{0}')
and lower(tc.constraint_type) in ('primary key')
and kcu.column_name is not null
;", m_Realm);
using (NpgsqlConnection conn = new NpgsqlConnection(m_ConnectionString))
using (NpgsqlCommand cmd = new NpgsqlCommand(query, conn))
{
conn.Open();
using (NpgsqlDataReader rdr = cmd.ExecuteReader())
{
while (rdr.Read())
{
// query produces 0 to many rows of single column, so always add the first item in each row
constraints.Add((string)rdr[0]);
}
}
return constraints;
}
}
public virtual T[] Get(string field, string key)
{
return Get(new string[] { field }, new string[] { key });
}
public virtual T[] Get(string[] fields, string[] keys)
{
if (fields.Length != keys.Length)
return new T[0];
List<string> terms = new List<string>();
using (NpgsqlConnection conn = new NpgsqlConnection(m_ConnectionString))
using (NpgsqlCommand cmd = new NpgsqlCommand())
{
for (int i = 0; i < fields.Length; i++)
{
if ( m_FieldTypes.ContainsKey(fields[i]) )
cmd.Parameters.Add(m_database.CreateParameter(fields[i], keys[i], m_FieldTypes[fields[i]]));
else
cmd.Parameters.Add(m_database.CreateParameter(fields[i], keys[i]));
terms.Add(" \"" + fields[i] + "\" = :" + fields[i]);
}
string where = String.Join(" AND ", terms.ToArray());
string query = String.Format("SELECT * FROM {0} WHERE {1}",
m_Realm, where);
cmd.Connection = conn;
cmd.CommandText = query;
conn.Open();
return DoQuery(cmd);
}
}
protected T[] DoQuery(NpgsqlCommand cmd)
{
List<T> result = new List<T>();
if (cmd.Connection == null)
{
cmd.Connection = new NpgsqlConnection(m_connectionString);
}
if (cmd.Connection.State == ConnectionState.Closed)
{
cmd.Connection.Open();
}
using (NpgsqlDataReader reader = cmd.ExecuteReader())
{
if (reader == null)
return new T[0];
CheckColumnNames(reader);
while (reader.Read())
{
T row = new T();
foreach (string name in m_Fields.Keys)
{
if (m_Fields[name].GetValue(row) is bool)
{
int v = Convert.ToInt32(reader[name]);
m_Fields[name].SetValue(row, v != 0 ? true : false);
}
else if (m_Fields[name].GetValue(row) is UUID)
{
UUID uuid = UUID.Zero;
UUID.TryParse(reader[name].ToString(), out uuid);
m_Fields[name].SetValue(row, uuid);
}
else if (m_Fields[name].GetValue(row) is int)
{
int v = Convert.ToInt32(reader[name]);
m_Fields[name].SetValue(row, v);
}
else
{
m_Fields[name].SetValue(row, reader[name]);
}
}
if (m_DataField != null)
{
Dictionary<string, string> data =
new Dictionary<string, string>();
foreach (string col in m_ColumnNames)
{
data[col] = reader[col].ToString();
if (data[col] == null)
data[col] = String.Empty;
}
m_DataField.SetValue(row, data);
}
result.Add(row);
}
return result.ToArray();
}
}
public virtual T[] Get(string where)
{
using (NpgsqlConnection conn = new NpgsqlConnection(m_ConnectionString))
using (NpgsqlCommand cmd = new NpgsqlCommand())
{
string query = String.Format("SELECT * FROM {0} WHERE {1}",
m_Realm, where);
cmd.Connection = conn;
cmd.CommandText = query;
//m_log.WarnFormat("[PGSQLGenericTable]: SELECT {0} WHERE {1}", m_Realm, where);
conn.Open();
return DoQuery(cmd);
}
}
public virtual T[] Get(string where, NpgsqlParameter parameter)
{
using (NpgsqlConnection conn = new NpgsqlConnection(m_ConnectionString))
using (NpgsqlCommand cmd = new NpgsqlCommand())
{
string query = String.Format("SELECT * FROM {0} WHERE {1}",
m_Realm, where);
cmd.Connection = conn;
cmd.CommandText = query;
//m_log.WarnFormat("[PGSQLGenericTable]: SELECT {0} WHERE {1}", m_Realm, where);
cmd.Parameters.Add(parameter);
conn.Open();
return DoQuery(cmd);
}
}
public virtual bool Store(T row)
{
List<string> constraintFields = GetConstraints();
List<KeyValuePair<string, string>> constraints = new List<KeyValuePair<string, string>>();
using (NpgsqlConnection conn = new NpgsqlConnection(m_ConnectionString))
using (NpgsqlCommand cmd = new NpgsqlCommand())
{
StringBuilder query = new StringBuilder();
List<String> names = new List<String>();
List<String> values = new List<String>();
foreach (FieldInfo fi in m_Fields.Values)
{
names.Add(fi.Name);
values.Add(":" + fi.Name);
// Temporarily return more information about what field is unexpectedly null for
// http://opensimulator.org/mantis/view.php?id=5403. This might be due to a bug in the
// InventoryTransferModule or we may be required to substitute a DBNull here.
if (fi.GetValue(row) == null)
throw new NullReferenceException(
string.Format(
"[PGSQL GENERIC TABLE HANDLER]: Trying to store field {0} for {1} which is unexpectedly null",
fi.Name, row));
if (constraintFields.Count > 0 && constraintFields.Contains(fi.Name))
{
constraints.Add(new KeyValuePair<string, string>(fi.Name, fi.GetValue(row).ToString() ));
}
if (m_FieldTypes.ContainsKey(fi.Name))
cmd.Parameters.Add(m_database.CreateParameter(fi.Name, fi.GetValue(row), m_FieldTypes[fi.Name]));
else
cmd.Parameters.Add(m_database.CreateParameter(fi.Name, fi.GetValue(row)));
}
if (m_DataField != null)
{
Dictionary<string, string> data =
(Dictionary<string, string>)m_DataField.GetValue(row);
foreach (KeyValuePair<string, string> kvp in data)
{
if (constraintFields.Count > 0 && constraintFields.Contains(kvp.Key))
{
constraints.Add(new KeyValuePair<string, string>(kvp.Key, kvp.Key));
}
names.Add(kvp.Key);
values.Add(":" + kvp.Key);
if (m_FieldTypes.ContainsKey(kvp.Key))
cmd.Parameters.Add(m_database.CreateParameter("" + kvp.Key, kvp.Value, m_FieldTypes[kvp.Key]));
else
cmd.Parameters.Add(m_database.CreateParameter("" + kvp.Key, kvp.Value));
}
}
query.AppendFormat("UPDATE {0} SET ", m_Realm);
int i = 0;
for (i = 0; i < names.Count - 1; i++)
{
query.AppendFormat("\"{0}\" = {1}, ", names[i], values[i]);
}
query.AppendFormat("\"{0}\" = {1} ", names[i], values[i]);
if (constraints.Count > 0)
{
List<string> terms = new List<string>();
for (int j = 0; j < constraints.Count; j++)
{
terms.Add(String.Format(" \"{0}\" = :{0}", constraints[j].Key));
}
string where = String.Join(" AND ", terms.ToArray());
query.AppendFormat(" WHERE {0} ", where);
}
cmd.Connection = conn;
cmd.CommandText = query.ToString();
conn.Open();
if (cmd.ExecuteNonQuery() > 0)
{
//m_log.WarnFormat("[PGSQLGenericTable]: Updating {0}", m_Realm);
return true;
}
else
{
// assume record has not yet been inserted
query = new StringBuilder();
query.AppendFormat("INSERT INTO {0} (\"", m_Realm);
query.Append(String.Join("\",\"", names.ToArray()));
query.Append("\") values (" + String.Join(",", values.ToArray()) + ")");
cmd.Connection = conn;
cmd.CommandText = query.ToString();
// m_log.WarnFormat("[PGSQLGenericTable]: Inserting into {0} sql {1}", m_Realm, cmd.CommandText);
if (conn.State != ConnectionState.Open)
conn.Open();
if (cmd.ExecuteNonQuery() > 0)
return true;
}
return false;
}
}
public virtual bool Delete(string field, string key)
{
return Delete(new string[] { field }, new string[] { key });
}
public virtual bool Delete(string[] fields, string[] keys)
{
if (fields.Length != keys.Length)
return false;
List<string> terms = new List<string>();
using (NpgsqlConnection conn = new NpgsqlConnection(m_ConnectionString))
using (NpgsqlCommand cmd = new NpgsqlCommand())
{
for (int i = 0; i < fields.Length; i++)
{
if (m_FieldTypes.ContainsKey(fields[i]))
cmd.Parameters.Add(m_database.CreateParameter(fields[i], keys[i], m_FieldTypes[fields[i]]));
else
cmd.Parameters.Add(m_database.CreateParameter(fields[i], keys[i]));
terms.Add(" \"" + fields[i] + "\" = :" + fields[i]);
}
string where = String.Join(" AND ", terms.ToArray());
string query = String.Format("DELETE FROM {0} WHERE {1}", m_Realm, where);
cmd.Connection = conn;
cmd.CommandText = query;
conn.Open();
if (cmd.ExecuteNonQuery() > 0)
{
//m_log.Warn("[PGSQLGenericTable]: " + deleteCommand);
return true;
}
return false;
}
}
public long GetCount(string field, string key)
{
return GetCount(new string[] { field }, new string[] { key });
}
public long GetCount(string[] fields, string[] keys)
{
if (fields.Length != keys.Length)
return 0;
List<string> terms = new List<string>();
using (NpgsqlCommand cmd = new NpgsqlCommand())
{
for (int i = 0; i < fields.Length; i++)
{
cmd.Parameters.AddWithValue(fields[i], keys[i]);
terms.Add("\"" + fields[i] + "\" = :" + fields[i]);
}
string where = String.Join(" and ", terms.ToArray());
string query = String.Format("select count(*) from {0} where {1}",
m_Realm, where);
cmd.CommandText = query;
Object result = DoQueryScalar(cmd);
return Convert.ToInt64(result);
}
}
public long GetCount(string where)
{
using (NpgsqlCommand cmd = new NpgsqlCommand())
{
string query = String.Format("select count(*) from {0} where {1}",
m_Realm, where);
cmd.CommandText = query;
object result = DoQueryScalar(cmd);
return Convert.ToInt64(result);
}
}
public object DoQueryScalar(NpgsqlCommand cmd)
{
using (NpgsqlConnection dbcon = new NpgsqlConnection(m_ConnectionString))
{
dbcon.Open();
cmd.Connection = dbcon;
return cmd.ExecuteScalar();
}
}
}
}
|