aboutsummaryrefslogtreecommitdiffstats
path: root/phpBB/phpbb/db/tools/mssql.php
blob: 29f816a8698050886199fa038f299c51f3a21750 (plain)
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
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
<?php
/**
 *
 * This file is part of the phpBB Forum Software package.
 *
 * @copyright (c) phpBB Limited <https://www.phpbb.com>
 * @license GNU General Public License, version 2 (GPL-2.0)
 *
 * For full copyright and license information, please see
 * the docs/CREDITS.txt file.
 *
 */

namespace phpbb\db\tools;

/**
 * Database Tools for handling cross-db actions such as altering columns, etc.
 * Currently not supported is returning SQL for creating tables.
 */
class mssql extends tools
{
	/**
	 * Is the used MS SQL Server a SQL Server 2000?
	 * @var bool
	 */
	protected $is_sql_server_2000;

	/**
	 * Get the column types for mssql based databases
	 *
	 * @return array
	 */
	public static function get_dbms_type_map()
	{
		return array(
			'mssql'		=> array(
				'INT:'		=> '[int]',
				'BINT'		=> '[float]',
				'ULINT'		=> '[int]',
				'UINT'		=> '[int]',
				'UINT:'		=> '[int]',
				'TINT:'		=> '[int]',
				'USINT'		=> '[int]',
				'BOOL'		=> '[int]',
				'VCHAR'		=> '[varchar] (255)',
				'VCHAR:'	=> '[varchar] (%d)',
				'CHAR:'		=> '[char] (%d)',
				'XSTEXT'	=> '[varchar] (1000)',
				'STEXT'		=> '[varchar] (3000)',
				'TEXT'		=> '[varchar] (8000)',
				'MTEXT'		=> '[text]',
				'XSTEXT_UNI'=> '[nvarchar] (100)',
				'STEXT_UNI'	=> '[nvarchar] (255)',
				'TEXT_UNI'	=> '[nvarchar] (4000)',
				'MTEXT_UNI'	=> '[ntext]',
				'TIMESTAMP'	=> '[int]',
				'DECIMAL'	=> '[float]',
				'DECIMAL:'	=> '[float]',
				'PDECIMAL'	=> '[float]',
				'PDECIMAL:'	=> '[float]',
				'VCHAR_UNI'	=> '[nvarchar] (255)',
				'VCHAR_UNI:'=> '[nvarchar] (%d)',
				'VCHAR_CI'	=> '[nvarchar] (255)',
				'VARBINARY'	=> '[varchar] (255)',
			),

			'mssqlnative'	=> array(
				'INT:'		=> '[int]',
				'BINT'		=> '[float]',
				'ULINT'		=> '[int]',
				'UINT'		=> '[int]',
				'UINT:'		=> '[int]',
				'TINT:'		=> '[int]',
				'USINT'		=> '[int]',
				'BOOL'		=> '[int]',
				'VCHAR'		=> '[varchar] (255)',
				'VCHAR:'	=> '[varchar] (%d)',
				'CHAR:'		=> '[char] (%d)',
				'XSTEXT'	=> '[varchar] (1000)',
				'STEXT'		=> '[varchar] (3000)',
				'TEXT'		=> '[varchar] (8000)',
				'MTEXT'		=> '[text]',
				'XSTEXT_UNI'=> '[nvarchar] (100)',
				'STEXT_UNI'	=> '[nvarchar] (255)',
				'TEXT_UNI'	=> '[nvarchar] (4000)',
				'MTEXT_UNI'	=> '[ntext]',
				'TIMESTAMP'	=> '[int]',
				'DECIMAL'	=> '[float]',
				'DECIMAL:'	=> '[float]',
				'PDECIMAL'	=> '[float]',
				'PDECIMAL:'	=> '[float]',
				'VCHAR_UNI'	=> '[nvarchar] (255)',
				'VCHAR_UNI:'=> '[nvarchar] (%d)',
				'VCHAR_CI'	=> '[nvarchar] (255)',
				'VARBINARY'	=> '[varchar] (255)',
			),
		);
	}

	/**
	* Constructor. Set DB Object and set {@link $return_statements return_statements}.
	*
	* @param \phpbb\db\driver\driver_interface	$db					Database connection
	* @param bool		$return_statements	True if only statements should be returned and no SQL being executed
	*/
	public function __construct(\phpbb\db\driver\driver_interface $db, $return_statements = false)
	{
		parent::__construct($db, $return_statements);

		// Determine mapping database type
		switch ($this->db->get_sql_layer())
		{
			case 'mssql_odbc':
				$this->sql_layer = 'mssql';
			break;

			case 'mssqlnative':
				$this->sql_layer = 'mssqlnative';
			break;
		}

		$this->dbms_type_map = self::get_dbms_type_map();
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_list_tables()
	{
		$sql = "SELECT name
			FROM sysobjects
			WHERE type='U'";
		$result = $this->db->sql_query($sql);

		$tables = array();
		while ($row = $this->db->sql_fetchrow($result))
		{
			$name = current($row);
			$tables[$name] = $name;
		}
		$this->db->sql_freeresult($result);

		return $tables;
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_create_table($table_name, $table_data)
	{
		// holds the DDL for a column
		$columns = $statements = array();

		if ($this->sql_table_exists($table_name))
		{
			return $this->_sql_run_sql($statements);
		}

		// Begin transaction
		$statements[] = 'begin';

		// Determine if we have created a PRIMARY KEY in the earliest
		$primary_key_gen = false;

		// Determine if the table requires a sequence
		$create_sequence = false;

		// Begin table sql statement
		$table_sql = 'CREATE TABLE [' . $table_name . '] (' . "\n";

		if (!isset($table_data['PRIMARY_KEY']))
		{
			$table_data['COLUMNS']['mssqlindex'] = array('UINT', null, 'auto_increment');
			$table_data['PRIMARY_KEY'] = 'mssqlindex';
		}

		// Iterate through the columns to create a table
		foreach ($table_data['COLUMNS'] as $column_name => $column_data)
		{
			// here lies an array, filled with information compiled on the column's data
			$prepared_column = $this->sql_prepare_column_data($table_name, $column_name, $column_data);

			if (isset($prepared_column['auto_increment']) && $prepared_column['auto_increment'] && strlen($column_name) > 26) // "${column_name}_gen"
			{
				trigger_error("Index name '${column_name}_gen' on table '$table_name' is too long. The maximum auto increment column length is 26 characters.", E_USER_ERROR);
			}

			// here we add the definition of the new column to the list of columns
			$columns[] = "\t [{$column_name}] " . $prepared_column['column_type_sql_default'];

			// see if we have found a primary key set due to a column definition if we have found it, we can stop looking
			if (!$primary_key_gen)
			{
				$primary_key_gen = isset($prepared_column['primary_key_set']) && $prepared_column['primary_key_set'];
			}

			// create sequence DDL based off of the existence of auto incrementing columns
			if (!$create_sequence && isset($prepared_column['auto_increment']) && $prepared_column['auto_increment'])
			{
				$create_sequence = $column_name;
			}
		}

		// this makes up all the columns in the create table statement
		$table_sql .= implode(",\n", $columns);

		// Close the table for two DBMS and add to the statements
		$table_sql .= "\n);";
		$statements[] = $table_sql;

		// we have yet to create a primary key for this table,
		// this means that we can add the one we really wanted instead
		if (!$primary_key_gen)
		{
			// Write primary key
			if (isset($table_data['PRIMARY_KEY']))
			{
				if (!is_array($table_data['PRIMARY_KEY']))
				{
					$table_data['PRIMARY_KEY'] = array($table_data['PRIMARY_KEY']);
				}

				// We need the data here
				$old_return_statements = $this->return_statements;
				$this->return_statements = true;

				$primary_key_stmts = $this->sql_create_primary_key($table_name, $table_data['PRIMARY_KEY']);
				foreach ($primary_key_stmts as $pk_stmt)
				{
					$statements[] = $pk_stmt;
				}

				$this->return_statements = $old_return_statements;
			}
		}

		// Write Keys
		if (isset($table_data['KEYS']))
		{
			foreach ($table_data['KEYS'] as $key_name => $key_data)
			{
				if (!is_array($key_data[1]))
				{
					$key_data[1] = array($key_data[1]);
				}

				$old_return_statements = $this->return_statements;
				$this->return_statements = true;

				$key_stmts = ($key_data[0] == 'UNIQUE') ? $this->sql_create_unique_index($table_name, $key_name, $key_data[1]) : $this->sql_create_index($table_name, $key_name, $key_data[1]);

				foreach ($key_stmts as $key_stmt)
				{
					$statements[] = $key_stmt;
				}

				$this->return_statements = $old_return_statements;
			}
		}

		// Commit Transaction
		$statements[] = 'commit';

		return $this->_sql_run_sql($statements);
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_list_columns($table_name)
	{
		$columns = array();

		$sql = "SELECT c.name
			FROM syscolumns c
			LEFT JOIN sysobjects o ON c.id = o.id
			WHERE o.name = '{$table_name}'";
		$result = $this->db->sql_query($sql);

		while ($row = $this->db->sql_fetchrow($result))
		{
			$column = strtolower(current($row));
			$columns[$column] = $column;
		}
		$this->db->sql_freeresult($result);

		return $columns;
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_index_exists($table_name, $index_name)
	{
		$sql = "EXEC sp_statistics '$table_name'";
		$result = $this->db->sql_query($sql);

		while ($row = $this->db->sql_fetchrow($result))
		{
			if ($row['TYPE'] == 3)
			{
				if (strtolower($row['INDEX_NAME']) == strtolower($index_name))
				{
					$this->db->sql_freeresult($result);
					return true;
				}
			}
		}
		$this->db->sql_freeresult($result);

		return false;
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_unique_index_exists($table_name, $index_name)
	{
		$sql = "EXEC sp_statistics '$table_name'";
		$result = $this->db->sql_query($sql);

		while ($row = $this->db->sql_fetchrow($result))
		{
			// Usually NON_UNIQUE is the column we want to check, but we allow for both
			if ($row['TYPE'] == 3)
			{
				if (strtolower($row['INDEX_NAME']) == strtolower($index_name))
				{
					$this->db->sql_freeresult($result);
					return true;
				}
			}
		}
		$this->db->sql_freeresult($result);

		return false;
	}

	/**
	 * {@inheritDoc}
	*/
	function sql_prepare_column_data($table_name, $column_name, $column_data)
	{
		if (strlen($column_name) > 30)
		{
			trigger_error("Column name '$column_name' on table '$table_name' is too long. The maximum is 30 characters.", E_USER_ERROR);
		}

		// Get type
		list($column_type, ) = $this->get_column_type($column_data[0]);

		// Adjust default value if db-dependent specified
		if (is_array($column_data[1]))
		{
			$column_data[1] = (isset($column_data[1][$this->sql_layer])) ? $column_data[1][$this->sql_layer] : $column_data[1]['default'];
		}

		$sql = '';

		$return_array = array();

		$sql .= " {$column_type} ";
		$sql_default = " {$column_type} ";

		// For adding columns we need the default definition
		if (!is_null($column_data[1]))
		{
			// For hexadecimal values do not use single quotes
			if (strpos($column_data[1], '0x') === 0)
			{
				$return_array['default'] = 'DEFAULT (' . $column_data[1] . ') ';
				$sql_default .= $return_array['default'];
			}
			else
			{
				$return_array['default'] = 'DEFAULT (' . ((is_numeric($column_data[1])) ? $column_data[1] : "'{$column_data[1]}'") . ') ';
				$sql_default .= $return_array['default'];
			}
		}

		if (isset($column_data[2]) && $column_data[2] == 'auto_increment')
		{
			// $sql .= 'IDENTITY (1, 1) ';
			$sql_default .= 'IDENTITY (1, 1) ';
		}

		$return_array['textimage'] = $column_type === '[text]';

		if (!is_null($column_data[1]) || (isset($column_data[2]) && $column_data[2] == 'auto_increment'))
		{
			$sql .= 'NOT NULL';
			$sql_default .= 'NOT NULL';
		}
		else
		{
			$sql .= 'NULL';
			$sql_default .= 'NULL';
		}

		$return_array['column_type_sql_default'] = $sql_default;

		$return_array['column_type_sql'] = $sql;

		return $return_array;
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_column_add($table_name, $column_name, $column_data, $inline = false)
	{
		$column_data = $this->sql_prepare_column_data($table_name, $column_name, $column_data);
		$statements = array();

		// Does not support AFTER, only through temporary table
		$statements[] = 'ALTER TABLE [' . $table_name . '] ADD [' . $column_name . '] ' . $column_data['column_type_sql_default'];

		return $this->_sql_run_sql($statements);
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_column_remove($table_name, $column_name, $inline = false)
	{
		$statements = array();

		// We need the data here
		$old_return_statements = $this->return_statements;
		$this->return_statements = true;

		$indexes = $this->get_existing_indexes($table_name, $column_name);
		$indexes = array_merge($indexes, $this->get_existing_indexes($table_name, $column_name, true));

		// Drop any indexes
		$recreate_indexes = array();
		if (!empty($indexes))
		{
			foreach ($indexes as $index_name => $index_data)
			{
				$result = $this->sql_index_drop($table_name, $index_name);
				$statements = array_merge($statements, $result);
				if (count($index_data) > 1)
				{
					// Remove this column from the index and recreate it
					$recreate_indexes[$index_name] = array_diff($index_data, array($column_name));
				}
			}
		}

		// Drop primary keys depending on this column
		$result = $this->mssql_get_drop_default_primary_key_queries($table_name, $column_name);
		$statements = array_merge($statements, $result);

		// Drop default value constraint
		$result = $this->mssql_get_drop_default_constraints_queries($table_name, $column_name);
		$statements = array_merge($statements, $result);

		// Remove the column
		$statements[] = 'ALTER TABLE [' . $table_name . '] DROP COLUMN [' . $column_name . ']';

		if (!empty($recreate_indexes))
		{
			// Recreate indexes after we removed the column
			foreach ($recreate_indexes as $index_name => $index_data)
			{
				$result = $this->sql_create_index($table_name, $index_name, $index_data);
				$statements = array_merge($statements, $result);
			}
		}

		$this->return_statements = $old_return_statements;

		return $this->_sql_run_sql($statements);
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_index_drop($table_name, $index_name)
	{
		$statements = array();

		$statements[] = 'DROP INDEX [' . $table_name . '].[' . $index_name . ']';

		return $this->_sql_run_sql($statements);
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_table_drop($table_name)
	{
		$statements = array();

		if (!$this->sql_table_exists($table_name))
		{
			return $this->_sql_run_sql($statements);
		}

		// the most basic operation, get rid of the table
		$statements[] = 'DROP TABLE ' . $table_name;

		return $this->_sql_run_sql($statements);
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_create_primary_key($table_name, $column, $inline = false)
	{
		$statements = array();

		$sql = "ALTER TABLE [{$table_name}] WITH NOCHECK ADD ";
		$sql .= "CONSTRAINT [PK_{$table_name}] PRIMARY KEY  CLUSTERED (";
		$sql .= '[' . implode("],\n\t\t[", $column) . ']';
		$sql .= ')';

		$statements[] = $sql;

		return $this->_sql_run_sql($statements);
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_create_unique_index($table_name, $index_name, $column)
	{
		$statements = array();

		if ($this->mssql_is_sql_server_2000())
		{
			$this->check_index_name_length($table_name, $index_name);
		}

		$statements[] = 'CREATE UNIQUE INDEX [' . $index_name . '] ON [' . $table_name . ']([' . implode('], [', $column) . '])';

		return $this->_sql_run_sql($statements);
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_create_index($table_name, $index_name, $column)
	{
		$statements = array();

		$this->check_index_name_length($table_name, $index_name);

		// remove index length
		$column = preg_replace('#:.*$#', '', $column);

		$statements[] = 'CREATE INDEX [' . $index_name . '] ON [' . $table_name . ']([' . implode('], [', $column) . '])';

		return $this->_sql_run_sql($statements);
	}

	/**
	 * {@inheritdoc}
	 */
	protected function get_max_index_name_length()
	{
		if ($this->mssql_is_sql_server_2000())
		{
			return parent::get_max_index_name_length();
		}
		else
		{
			return 128;
		}
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_list_index($table_name)
	{
		$index_array = array();
		$sql = "EXEC sp_statistics '$table_name'";
		$result = $this->db->sql_query($sql);
		while ($row = $this->db->sql_fetchrow($result))
		{
			if ($row['TYPE'] == 3)
			{
				$index_array[] = strtolower($row['INDEX_NAME']);
			}
		}
		$this->db->sql_freeresult($result);

		return $index_array;
	}

	/**
	 * {@inheritDoc}
	 */
	function sql_column_change($table_name, $column_name, $column_data, $inline = false)
	{
		$column_data = $this->sql_prepare_column_data($table_name, $column_name, $column_data);
		$statements = array();

		// We need the data here
		$old_return_statements = $this->return_statements;
		$this->return_statements = true;

		$indexes = $this->get_existing_indexes($table_name, $column_name);
		$unique_indexes = $this->get_existing_indexes($table_name, $column_name, true);

		// Drop any indexes
		if (!empty($indexes) || !empty($unique_indexes))
		{
			$drop_indexes = array_merge(array_keys($indexes), array_keys($unique_indexes));
			foreach ($drop_indexes as $index_name)
			{
				$result = $this->sql_index_drop($table_name, $index_name);
				$statements = array_merge($statements, $result);
			}
		}

		// Drop default value constraint
		$result = $this->mssql_get_drop_default_constraints_queries($table_name, $column_name);
		$statements = array_merge($statements, $result);

		// Change the column
		$statements[] = 'ALTER TABLE [' . $table_name . '] ALTER COLUMN [' . $column_name . '] ' . $column_data['column_type_sql'];

		if (!empty($column_data['default']) && !$this->mssql_is_column_identity($table_name, $column_name))
		{
			// Add new default value constraint
			$statements[] = 'ALTER TABLE [' . $table_name . '] ADD CONSTRAINT [DF_' . $table_name . '_' . $column_name . '_1] ' . $column_data['default'] . ' FOR [' . $column_name . ']';
		}

		if (!empty($indexes))
		{
			// Recreate indexes after we changed the column
			foreach ($indexes as $index_name => $index_data)
			{
				$result = $this->sql_create_index($table_name, $index_name, $index_data);
				$statements = array_merge($statements, $result);
			}
		}

		if (!empty($unique_indexes))
		{
			// Recreate unique indexes after we changed the column
			foreach ($unique_indexes as $index_name => $index_data)
			{
				$result = $this->sql_create_unique_index($table_name, $index_name, $index_data);
				$statements = array_merge($statements, $result);
			}
		}

		$this->return_statements = $old_return_statements;

		return $this->_sql_run_sql($statements);
	}

	/**
	* Get queries to drop the default constraints of a column
	*
	* We need to drop the default constraints of a column,
	* before being able to change their type or deleting them.
	*
	* @param string $table_name
	* @param string $column_name
	* @return array		Array with SQL statements
	*/
	protected function mssql_get_drop_default_constraints_queries($table_name, $column_name)
	{
		$statements = array();
		if ($this->mssql_is_sql_server_2000())
		{
			// http://msdn.microsoft.com/en-us/library/aa175912%28v=sql.80%29.aspx
			// Deprecated in SQL Server 2005
			$sql = "SELECT so.name AS def_name
				FROM sysobjects so
				JOIN sysconstraints sc ON so.id = sc.constid
				WHERE object_name(so.parent_obj) = '{$table_name}'
					AND so.xtype = 'D'
					AND sc.colid = (SELECT colid FROM syscolumns
						WHERE id = object_id('{$table_name}')
							AND name = '{$column_name}')";
		}
		else
		{
			$sql = "SELECT dobj.name AS def_name
				FROM sys.columns col
					LEFT OUTER JOIN sys.objects dobj ON (dobj.object_id = col.default_object_id AND dobj.type = 'D')
				WHERE col.object_id = object_id('{$table_name}')
					AND col.name = '{$column_name}'
					AND dobj.name IS NOT NULL";
		}

		$result = $this->db->sql_query($sql);
		while ($row = $this->db->sql_fetchrow($result))
		{
			$statements[] = 'ALTER TABLE [' . $table_name . '] DROP CONSTRAINT [' . $row['def_name'] . ']';
		}
		$this->db->sql_freeresult($result);

		return $statements;
	}

	/**
	 * Get queries to drop the primary keys depending on the specified column
	 *
	 * We need to drop primary keys depending on this column before being able
	 * to delete them.
	 *
	 * @param string $table_name
	 * @param string $column_name
	 * @return array		Array with SQL statements
	 */
	protected function mssql_get_drop_default_primary_key_queries($table_name, $column_name)
	{
		$statements = array();

		$sql = "SELECT ccu.CONSTRAINT_NAME, ccu.COLUMN_NAME
			FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS tc
				JOIN INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE ccu ON tc.CONSTRAINT_NAME = ccu.Constraint_name
			WHERE tc.TABLE_NAME = '{$table_name}'
				AND tc.CONSTRAINT_TYPE = 'Primary Key'
				AND ccu.COLUMN_NAME = '{$column_name}'";

		$result = $this->db->sql_query($sql);

		while ($primary_key = $this->db->sql_fetchrow($result))
		{
			$statements[] = 'ALTER TABLE [' . $table_name . '] DROP CONSTRAINT [' . $primary_key['CONSTRAINT_NAME'] . ']';
		}
		$this->db->sql_freeresult($result);

		return $statements;
	}

	/**
	 * Checks to see if column is an identity column
	 *
	 * Identity columns cannot have defaults set for them.
	 *
	 * @param string $table_name
	 * @param string $column_name
	 * @return bool		true if identity, false if not
	 */
	protected function mssql_is_column_identity($table_name, $column_name)
	{
		if ($this->mssql_is_sql_server_2000())
		{
			// http://msdn.microsoft.com/en-us/library/aa175912%28v=sql.80%29.aspx
			// Deprecated in SQL Server 2005
			$sql = "SELECT COLUMNPROPERTY(object_id('{$table_name}'), '{$column_name}', 'IsIdentity') AS is_identity";
		}
		else
		{
			$sql = "SELECT is_identity FROM sys.columns
					WHERE object_id = object_id('{$table_name}')
					AND name = '{$column_name}'";
		}

		$result = $this->db->sql_query($sql);
		$is_identity = $this->db->sql_fetchfield('is_identity');
		$this->db->sql_freeresult($result);

		return (bool) $is_identity;
	}

	/**
	* Get a list with existing indexes for the column
	*
	* @param string $table_name
	* @param string $column_name
	* @param bool $unique Should we get unique indexes or normal ones
	* @return array		Array with Index name => columns
	*/
	public function get_existing_indexes($table_name, $column_name, $unique = false)
	{
		$existing_indexes = array();
		if ($this->mssql_is_sql_server_2000())
		{
			// http://msdn.microsoft.com/en-us/library/aa175912%28v=sql.80%29.aspx
			// Deprecated in SQL Server 2005
			$sql = "SELECT DISTINCT ix.name AS phpbb_index_name
				FROM sysindexes ix
				INNER JOIN sysindexkeys ixc
					ON ixc.id = ix.id
						AND ixc.indid = ix.indid
				INNER JOIN syscolumns cols
					ON cols.colid = ixc.colid
						AND cols.id = ix.id
				WHERE ix.id = object_id('{$table_name}')
					AND cols.name = '{$column_name}'
					AND INDEXPROPERTY(ix.id, ix.name, 'IsUnique') = " . ($unique ? '1' : '0');
		}
		else
		{
			$sql = "SELECT DISTINCT ix.name AS phpbb_index_name
				FROM sys.indexes ix
				INNER JOIN sys.index_columns ixc
					ON ixc.object_id = ix.object_id
						AND ixc.index_id = ix.index_id
				INNER JOIN sys.columns cols
					ON cols.column_id = ixc.column_id
						AND cols.object_id = ix.object_id
				WHERE ix.object_id = object_id('{$table_name}')
					AND cols.name = '{$column_name}'
					AND ix.is_primary_key = 0
					AND ix.is_unique = " . ($unique ? '1' : '0');
		}

		$result = $this->db->sql_query($sql);
		while ($row = $this->db->sql_fetchrow($result))
		{
			if (!isset($row['is_unique']) || ($unique && $row['is_unique'] == 'UNIQUE') || (!$unique && $row['is_unique'] == 'NONUNIQUE'))
			{
				$existing_indexes[$row['phpbb_index_name']] = array();
			}
		}
		$this->db->sql_freeresult($result);

		if (empty($existing_indexes))
		{
			return array();
		}

		if ($this->mssql_is_sql_server_2000())
		{
			$sql = "SELECT DISTINCT ix.name AS phpbb_index_name, cols.name AS phpbb_column_name
				FROM sysindexes ix
				INNER JOIN sysindexkeys ixc
					ON ixc.id = ix.id
						AND ixc.indid = ix.indid
				INNER JOIN syscolumns cols
					ON cols.colid = ixc.colid
						AND cols.id = ix.id
				WHERE ix.id = object_id('{$table_name}')
					AND " . $this->db->sql_in_set('ix.name', array_keys($existing_indexes));
		}
		else
		{
			$sql = "SELECT DISTINCT ix.name AS phpbb_index_name, cols.name AS phpbb_column_name
				FROM sys.indexes ix
				INNER JOIN sys.index_columns ixc
					ON ixc.object_id = ix.object_id
						AND ixc.index_id = ix.index_id
				INNER JOIN sys.columns cols
					ON cols.column_id = ixc.column_id
						AND cols.object_id = ix.object_id
				WHERE ix.object_id = object_id('{$table_name}')
					AND " . $this->db->sql_in_set('ix.name', array_keys($existing_indexes));
		}

		$result = $this->db->sql_query($sql);
		while ($row = $this->db->sql_fetchrow($result))
		{
			$existing_indexes[$row['phpbb_index_name']][] = $row['phpbb_column_name'];
		}
		$this->db->sql_freeresult($result);

		return $existing_indexes;
	}

	/**
	* Is the used MS SQL Server a SQL Server 2000?
	*
	* @return bool
	*/
	protected function mssql_is_sql_server_2000()
	{
		if ($this->is_sql_server_2000 === null)
		{
			$sql = "SELECT CAST(SERVERPROPERTY('productversion') AS VARCHAR(25)) AS mssql_version";
			$result = $this->db->sql_query($sql);
			$properties = $this->db->sql_fetchrow($result);
			$this->db->sql_freeresult($result);
			$this->is_sql_server_2000 = $properties['mssql_version'][0] == '8';
		}

		return $this->is_sql_server_2000;
	}

}