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 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159 1160 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 1354
|
import datetime
import decimal
import random
from sqlalchemy import Column
from sqlalchemy import DDL
from sqlalchemy import event
from sqlalchemy import exc
from sqlalchemy import ForeignKey
from sqlalchemy import ForeignKeyConstraint
from sqlalchemy import Identity
from sqlalchemy import Index
from sqlalchemy import inspect
from sqlalchemy import Integer
from sqlalchemy import MetaData
from sqlalchemy import PrimaryKeyConstraint
from sqlalchemy import schema
from sqlalchemy import Table
from sqlalchemy import testing
from sqlalchemy import types
from sqlalchemy import types as sqltypes
from sqlalchemy.dialects import mssql
from sqlalchemy.dialects.mssql import base
from sqlalchemy.dialects.mssql.information_schema import tables
from sqlalchemy.pool import NullPool
from sqlalchemy.schema import CreateIndex
from sqlalchemy.testing import AssertsCompiledSQL
from sqlalchemy.testing import ComparesTables
from sqlalchemy.testing import eq_
from sqlalchemy.testing import expect_raises
from sqlalchemy.testing import expect_raises_message
from sqlalchemy.testing import fixtures
from sqlalchemy.testing import in_
from sqlalchemy.testing import is_
from sqlalchemy.testing import is_true
from sqlalchemy.testing import mock
from sqlalchemy.testing import provision
from sqlalchemy.testing.assertions import is_false
class ReflectionTest(fixtures.TestBase, ComparesTables, AssertsCompiledSQL):
__only_on__ = "mssql"
__backend__ = True
def test_basic_reflection(self, metadata, connection):
meta = metadata
users = Table(
"engine_users",
meta,
Column("user_id", types.INT, primary_key=True),
Column("user_name", types.VARCHAR(20), nullable=False),
Column("test1", types.CHAR(5), nullable=False),
Column("test2", types.Float(5), nullable=False),
Column("test2.5", types.Float(), nullable=False),
Column("test3", types.Text()),
Column("test4", types.Numeric, nullable=False),
Column("test4.5", types.Numeric(10, 2), nullable=False),
Column("test5", types.DateTime),
Column(
"parent_user_id",
types.Integer,
ForeignKey("engine_users.user_id"),
),
Column("test6", types.DateTime, nullable=False),
Column("test7", types.Text()),
Column("test8", types.LargeBinary()),
Column("test_passivedefault2", types.Integer, server_default="5"),
Column("test9", types.BINARY(100)),
Column("test_numeric", types.Numeric()),
)
addresses = Table(
"engine_email_addresses",
meta,
Column("address_id", types.Integer, primary_key=True),
Column(
"remote_user_id", types.Integer, ForeignKey(users.c.user_id)
),
Column("email_address", types.String(20)),
)
meta.create_all(connection)
meta2 = MetaData()
reflected_users = Table(
"engine_users", meta2, autoload_with=connection
)
reflected_addresses = Table(
"engine_email_addresses",
meta2,
autoload_with=connection,
)
self.assert_tables_equal(users, reflected_users)
self.assert_tables_equal(addresses, reflected_addresses)
@testing.combinations(
(mssql.XML, "XML"),
(mssql.IMAGE, "IMAGE"),
(mssql.MONEY, "MONEY"),
(mssql.NUMERIC(10, 2), "NUMERIC(10, 2)"),
(mssql.FLOAT, "FLOAT(53)"),
(mssql.REAL, "REAL"),
# FLOAT(5) comes back as REAL
(mssql.FLOAT(5), "REAL"),
argnames="type_obj,ddl",
)
def test_assorted_types(self, metadata, connection, type_obj, ddl):
table = Table("type_test", metadata, Column("col1", type_obj))
table.create(connection)
m2 = MetaData()
table2 = Table("type_test", m2, autoload_with=connection)
self.assert_compile(
schema.CreateTable(table2),
"CREATE TABLE type_test (col1 %s NULL)" % ddl,
)
def test_identity(self, metadata, connection):
table = Table(
"identity_test",
metadata,
Column(
"col1",
Integer,
mssql_identity_start=2,
mssql_identity_increment=3,
primary_key=True,
),
)
with testing.expect_deprecated(
"The dialect options 'mssql_identity_start' and"
):
table.create(connection)
meta2 = MetaData()
table2 = Table("identity_test", meta2, autoload_with=connection)
eq_(table2.c["col1"].dialect_options["mssql"]["identity_start"], None)
eq_(
table2.c["col1"].dialect_options["mssql"]["identity_increment"],
None,
)
eq_(table2.c["col1"].identity.start, 2)
eq_(table2.c["col1"].identity.increment, 3)
def test_skip_types(self, connection):
connection.exec_driver_sql(
"create table foo (id integer primary key, data xml)"
)
with mock.patch.object(
connection.dialect, "ischema_names", {"int": mssql.INTEGER}
):
with testing.expect_warnings(
"Did not recognize type 'xml' of column 'data'"
):
eq_(
inspect(connection).get_columns("foo"),
[
{
"name": "id",
"type": testing.eq_type_affinity(sqltypes.INTEGER),
"nullable": False,
"default": None,
"autoincrement": False,
"comment": None,
},
{
"name": "data",
"type": testing.eq_type_affinity(
sqltypes.NullType
),
"nullable": True,
"default": None,
"autoincrement": False,
"comment": None,
},
],
)
def test_cross_schema_fk_pk_name_overlaps(self, metadata, connection):
# test for issue #4228
Table(
"subject",
metadata,
Column("id", Integer),
PrimaryKeyConstraint("id", name="subj_pk"),
schema=testing.config.test_schema,
)
Table(
"referrer",
metadata,
Column("id", Integer, primary_key=True),
Column(
"sid",
ForeignKey(
"%s.subject.id" % testing.config.test_schema,
name="fk_subject",
),
),
schema=testing.config.test_schema,
)
Table(
"subject",
metadata,
Column("id", Integer),
PrimaryKeyConstraint("id", name="subj_pk"),
schema=testing.config.test_schema_2,
)
metadata.create_all(connection)
insp = inspect(connection)
eq_(
insp.get_foreign_keys("referrer", testing.config.test_schema),
[
{
"name": "fk_subject",
"constrained_columns": ["sid"],
"referred_schema": "test_schema",
"referred_table": "subject",
"referred_columns": ["id"],
"options": {},
}
],
)
def test_table_name_that_is_greater_than_16_chars(
self, metadata, connection
):
Table(
"ABCDEFGHIJKLMNOPQRSTUVWXYZ",
metadata,
Column("id", Integer, primary_key=True),
Column("foo", Integer),
Index("foo_idx", "foo"),
)
metadata.create_all(connection)
t = Table(
"ABCDEFGHIJKLMNOPQRSTUVWXYZ", MetaData(), autoload_with=connection
)
eq_(t.name, "ABCDEFGHIJKLMNOPQRSTUVWXYZ")
@testing.combinations(
("local_temp", "#tmp", True),
("global_temp", "##tmp", True),
("nonexistent", "#no_es_bueno", False),
id_="iaa",
argnames="table_name, exists",
)
def test_temporary_table(self, metadata, connection, table_name, exists):
if exists:
tt = Table(
table_name,
metadata,
Column("id", Integer, primary_key=True),
Column("txt", mssql.NVARCHAR(50)),
Column("dt2", mssql.DATETIME2),
)
tt.create(connection)
connection.execute(
tt.insert(),
[
{
"id": 1,
"txt": "foo",
"dt2": datetime.datetime(2020, 1, 1, 1, 1, 1),
},
{
"id": 2,
"txt": "bar",
"dt2": datetime.datetime(2020, 2, 2, 2, 2, 2),
},
],
)
if not exists:
with expect_raises(exc.NoSuchTableError):
Table(
table_name,
metadata,
autoload_with=connection,
)
else:
tmp_t = Table(table_name, metadata, autoload_with=connection)
result = connection.execute(
tmp_t.select().where(tmp_t.c.id == 2)
).fetchall()
eq_(
result,
[(2, "bar", datetime.datetime(2020, 2, 2, 2, 2, 2))],
)
@testing.combinations(
("local_temp", "#tmp", True),
("global_temp", "##tmp", True),
("nonexistent", "#no_es_bueno", False),
id_="iaa",
argnames="table_name, exists",
)
def test_has_table_temporary(
self, metadata, connection, table_name, exists
):
if exists:
tt = Table(
table_name,
metadata,
Column("id", Integer),
)
tt.create(connection)
found_it = testing.db.dialect.has_table(connection, table_name)
eq_(found_it, exists)
def test_has_table_temp_not_present_but_another_session(self):
"""test #6910"""
with testing.db.connect() as c1, testing.db.connect() as c2:
try:
with c1.begin():
c1.exec_driver_sql(
"create table #myveryveryuniquetemptablename (a int)"
)
assert not c2.dialect.has_table(
c2, "#myveryveryuniquetemptablename"
)
finally:
with c1.begin():
c1.exec_driver_sql(
"drop table #myveryveryuniquetemptablename"
)
def test_has_table_temp_temp_present_both_sessions(self):
"""test #7168, continues from #6910"""
with testing.db.connect() as c1, testing.db.connect() as c2:
try:
with c1.begin():
c1.exec_driver_sql(
"create table #myveryveryuniquetemptablename (a int)"
)
with c2.begin():
c2.exec_driver_sql(
"create table #myveryveryuniquetemptablename (a int)"
)
assert c2.dialect.has_table(
c2, "#myveryveryuniquetemptablename"
)
c2.rollback()
finally:
with c1.begin():
c1.exec_driver_sql(
"drop table #myveryveryuniquetemptablename"
)
with c2.begin():
c2.exec_driver_sql(
"drop table #myveryveryuniquetemptablename"
)
@testing.fixture
def temp_db_alt_collation_fixture(
self, connection_no_trans, testing_engine
):
temp_db_name = "%s_different_collation" % (
provision.FOLLOWER_IDENT or "default"
)
cnxn = connection_no_trans.execution_options(
isolation_level="AUTOCOMMIT"
)
cnxn.exec_driver_sql(f"DROP DATABASE IF EXISTS {temp_db_name}")
cnxn.exec_driver_sql(
f"CREATE DATABASE {temp_db_name} COLLATE Danish_Norwegian_CI_AS"
)
eng = testing_engine(
url=testing.db.url.set(database=temp_db_name),
options=dict(poolclass=NullPool),
)
yield eng
cnxn.exec_driver_sql(f"DROP DATABASE IF EXISTS {temp_db_name}")
def test_global_temp_different_collation(
self, temp_db_alt_collation_fixture
):
"""test #8035"""
tname = f"##foo{random.randint(1, 1000000)}"
with temp_db_alt_collation_fixture.connect() as conn:
conn.exec_driver_sql(f"CREATE TABLE {tname} (id int primary key)")
conn.commit()
eq_(
inspect(conn).get_columns(tname),
[
{
"name": "id",
"type": testing.eq_type_affinity(sqltypes.INTEGER),
"nullable": False,
"default": None,
"autoincrement": False,
"comment": None,
}
],
)
Table(tname, MetaData(), autoload_with=conn)
@testing.combinations(
("test_schema"),
("[test_schema]"),
argnames="schema_value",
)
@testing.variation(
"reflection_operation", ["has_table", "reflect_table", "get_columns"]
)
def test_has_table_with_single_token_schema(
self, metadata, connection, schema_value, reflection_operation
):
"""test for #9133"""
tt = Table(
"test", metadata, Column("id", Integer), schema=schema_value
)
tt.create(connection)
if reflection_operation.has_table:
is_true(inspect(connection).has_table("test", schema=schema_value))
elif reflection_operation.reflect_table:
m2 = MetaData()
Table("test", m2, autoload_with=connection, schema=schema_value)
elif reflection_operation.get_columns:
is_true(
inspect(connection).get_columns("test", schema=schema_value)
)
else:
reflection_operation.fail()
def test_db_qualified_items(self, metadata, connection):
Table("foo", metadata, Column("id", Integer, primary_key=True))
Table(
"bar",
metadata,
Column("id", Integer, primary_key=True),
Column("foo_id", Integer, ForeignKey("foo.id", name="fkfoo")),
)
metadata.create_all(connection)
dbname = connection.exec_driver_sql("select db_name()").scalar()
owner = connection.exec_driver_sql("SELECT user_name()").scalar()
referred_schema = "%(dbname)s.%(owner)s" % {
"dbname": dbname,
"owner": owner,
}
inspector = inspect(connection)
bar_via_db = inspector.get_foreign_keys("bar", schema=referred_schema)
eq_(
bar_via_db,
[
{
"referred_table": "foo",
"referred_columns": ["id"],
"referred_schema": referred_schema,
"name": "fkfoo",
"constrained_columns": ["foo_id"],
"options": {},
}
],
)
assert inspect(connection).has_table("bar", schema=referred_schema)
m2 = MetaData()
Table(
"bar",
m2,
schema=referred_schema,
autoload_with=connection,
)
eq_(m2.tables["%s.foo" % referred_schema].schema, referred_schema)
def test_fk_on_unique_index(self, metadata, connection):
# test for issue #7160
Table(
"uidx_parent",
metadata,
Column("id", Integer, primary_key=True),
Column("uidx_col1", Integer, nullable=False),
Column("uidx_col2", Integer, nullable=False),
Index(
"UIDX_composite",
"uidx_col1",
"uidx_col2",
unique=True,
),
)
Table(
"uidx_child",
metadata,
Column("id", Integer, primary_key=True),
Column("parent_uidx_col1", Integer, nullable=False),
Column("parent_uidx_col2", Integer, nullable=False),
ForeignKeyConstraint(
["parent_uidx_col1", "parent_uidx_col2"],
["uidx_parent.uidx_col1", "uidx_parent.uidx_col2"],
name="FK_uidx_parent",
),
)
metadata.create_all(connection)
inspector = inspect(connection)
fk_info = inspector.get_foreign_keys("uidx_child")
eq_(
fk_info,
[
{
"referred_table": "uidx_parent",
"referred_columns": ["uidx_col1", "uidx_col2"],
"referred_schema": None,
"name": "FK_uidx_parent",
"constrained_columns": [
"parent_uidx_col1",
"parent_uidx_col2",
],
"options": {},
}
],
)
def test_fk_with_same_column_name_as_pk_idx(self, metadata, connection):
"""test #12907"""
# Create table A with primary key AId and a unique index IX_A_AId
Table(
"a",
metadata,
Column("aid", Integer, nullable=False),
Column("name", types.String(50)),
PrimaryKeyConstraint("aid", name="PK_A"),
).create(connection)
# IMPORTANT - create unique index on a *first* before creating
# FK on B, this affects how the FK is generated in SQL server
connection.exec_driver_sql("CREATE UNIQUE INDEX IX_A_AId ON a (aid)")
# Create table B with foreign key column AId referencing A(AId)
# and an index with the same name IX_A_AId
Table(
"b",
metadata,
Column("id", Integer, Identity(), primary_key=True),
Column("aid", Integer),
ForeignKeyConstraint(["aid"], ["a.aid"], name="FK_B_A"),
).create(connection)
connection.exec_driver_sql("CREATE INDEX IX_A_AId ON B(aid)")
m2 = MetaData()
table_b = Table("b", m2, autoload_with=connection)
fks = list(table_b.foreign_keys)
eq_(len(fks), 1)
eq_(fks[0].parent.name, "aid")
eq_(fks[0].column.table.name, "a")
eq_(fks[0].column.name, "aid")
def test_indexes_cols(self, metadata, connection):
t1 = Table("t", metadata, Column("x", Integer), Column("y", Integer))
Index("foo", t1.c.x, t1.c.y)
metadata.create_all(connection)
m2 = MetaData()
t2 = Table("t", m2, autoload_with=connection)
eq_(set(list(t2.indexes)[0].columns), {t2.c["x"], t2.c.y})
def test_indexes_cols_with_commas(self, metadata, connection):
t1 = Table(
"t",
metadata,
Column("x, col", Integer, key="x"),
Column("y", Integer),
)
Index("foo", t1.c.x, t1.c.y)
metadata.create_all(connection)
m2 = MetaData()
t2 = Table("t", m2, autoload_with=connection)
eq_(set(list(t2.indexes)[0].columns), {t2.c["x, col"], t2.c.y})
def test_indexes_cols_with_spaces(self, metadata, connection):
t1 = Table(
"t",
metadata,
Column("x col", Integer, key="x"),
Column("y", Integer),
)
Index("foo", t1.c.x, t1.c.y)
metadata.create_all(connection)
m2 = MetaData()
t2 = Table("t", m2, autoload_with=connection)
eq_(set(list(t2.indexes)[0].columns), {t2.c["x col"], t2.c.y})
def test_indexes_with_filtered(self, metadata, connection):
t1 = Table(
"t",
metadata,
Column("id", Integer, primary_key=True),
Column("x", types.String(20)),
Column("y", types.Integer),
)
Index("idx_x", t1.c.x, mssql_where=t1.c.x == "test")
Index("idx_y", t1.c.y, mssql_where=t1.c.y >= 5)
metadata.create_all(connection)
ind = testing.db.dialect.get_indexes(connection, "t", None)
filtered_indexes = []
for ix in ind:
if "dialect_options" in ix:
filtered_indexes.append(ix["dialect_options"]["mssql_where"])
eq_(sorted(filtered_indexes), ["([x]='test')", "([y]>=(5))"])
t2 = Table("t", MetaData(), autoload_with=connection)
idx = list(sorted(t2.indexes, key=lambda idx: idx.name))[0]
self.assert_compile(
CreateIndex(idx),
"CREATE NONCLUSTERED INDEX idx_x ON t (x) WHERE ([x]='test')",
)
def test_index_reflection_clustered(self, metadata, connection):
"""
when the result of get_indexes() is used to build an index it should
include the CLUSTERED keyword when appropriate
"""
t1 = Table(
"t",
metadata,
Column("id", Integer),
Column("x", types.String(20)),
Column("y", types.Integer),
)
Index("idx_x", t1.c.x, mssql_clustered=True)
Index("idx_y", t1.c.y)
metadata.create_all(connection)
ind = testing.db.dialect.get_indexes(connection, "t", None)
clustered_index = ""
for ix in ind:
if ix["dialect_options"]["mssql_clustered"]:
clustered_index = ix["name"]
eq_(clustered_index, "idx_x")
t2 = Table("t", MetaData(), autoload_with=connection)
idx = list(sorted(t2.indexes, key=lambda idx: idx.name))[0]
self.assert_compile(
CreateIndex(idx), "CREATE CLUSTERED INDEX idx_x ON t (x)"
)
def test_index_reflection_filtered_and_clustered(
self, metadata, connection
):
"""
table with one filtered index and one clustered index so each index
will have different dialect_options keys
"""
t1 = Table(
"t",
metadata,
Column("id", Integer),
Column("x", types.String(20)),
Column("y", types.Integer),
)
Index("idx_x", t1.c.x, mssql_clustered=True)
Index("idx_y", t1.c.y, mssql_where=t1.c.y >= 5)
metadata.create_all(connection)
ind = testing.db.dialect.get_indexes(connection, "t", None)
clustered_index = ""
for ix in ind:
if ix["dialect_options"]["mssql_clustered"]:
clustered_index = ix["name"]
is_false("mssql_columnstore" in ix["dialect_options"])
eq_(clustered_index, "idx_x")
filtered_indexes = []
for ix in ind:
if "dialect_options" in ix:
if "mssql_where" in ix["dialect_options"]:
filtered_indexes.append(
ix["dialect_options"]["mssql_where"]
)
eq_(sorted(filtered_indexes), ["([y]>=(5))"])
t2 = Table("t", MetaData(), autoload_with=connection)
clustered_idx = list(
sorted(t2.indexes, key=lambda clustered_idx: clustered_idx.name)
)[0]
filtered_idx = list(
sorted(t2.indexes, key=lambda filtered_idx: filtered_idx.name)
)[1]
self.assert_compile(
CreateIndex(clustered_idx), "CREATE CLUSTERED INDEX idx_x ON t (x)"
)
self.assert_compile(
CreateIndex(filtered_idx),
"CREATE NONCLUSTERED INDEX idx_y ON t (y) WHERE ([y]>=(5))",
)
def test_index_reflection_nonclustered(self, metadata, connection):
"""
one index created by specifying mssql_clustered=False
one created without specifying mssql_clustered property so it will
use default of NONCLUSTERED.
When reflected back mssql_clustered=False should be included in both
"""
t1 = Table(
"t",
metadata,
Column("id", Integer),
Column("x", types.String(20)),
Column("y", types.Integer),
)
Index("idx_x", t1.c.x, mssql_clustered=False)
Index("idx_y", t1.c.y)
metadata.create_all(connection)
ind = testing.db.dialect.get_indexes(connection, "t", None)
for ix in ind:
assert ix["dialect_options"]["mssql_clustered"] == False
is_false("mssql_columnstore" in ix["dialect_options"])
t2 = Table("t", MetaData(), autoload_with=connection)
idx = list(sorted(t2.indexes, key=lambda idx: idx.name))[0]
self.assert_compile(
CreateIndex(idx), "CREATE NONCLUSTERED INDEX idx_x ON t (x)"
)
def test_index_column_order_clustered(self, metadata, connection):
"""test for #12894"""
test_table = Table(
"t",
metadata,
Column("id", Integer, primary_key=True),
Column("x", Integer),
Column("y", Integer),
PrimaryKeyConstraint("id", mssql_clustered=False),
)
Index(
"idx_x",
test_table.c.y,
test_table.c.id,
test_table.c.x,
mssql_clustered=True,
)
metadata.create_all(connection)
indexes = testing.db.dialect.get_indexes(connection, "t", None)
eq_(indexes[0]["column_names"], ["y", "id", "x"])
@testing.only_if("mssql>=12")
def test_index_reflection_colstore_clustered(self, metadata, connection):
t1 = Table(
"t",
metadata,
Column("id", Integer),
Column("x", types.String(20)),
Column("y", types.Integer),
Index("idx_x", mssql_clustered=True, mssql_columnstore=True),
)
Index("idx_y", t1.c.y)
metadata.create_all(connection)
ind = testing.db.dialect.get_indexes(connection, "t", None)
for ix in ind:
if ix["name"] == "idx_x":
is_true(ix["dialect_options"]["mssql_clustered"])
is_true(ix["dialect_options"]["mssql_columnstore"])
eq_(ix["dialect_options"]["mssql_include"], [])
eq_(ix["column_names"], [])
else:
is_false(ix["dialect_options"]["mssql_clustered"])
is_false("mssql_columnstore" in ix["dialect_options"])
t2 = Table("t", MetaData(), autoload_with=connection)
idx = list(sorted(t2.indexes, key=lambda idx: idx.name))[0]
self.assert_compile(
CreateIndex(idx), "CREATE CLUSTERED COLUMNSTORE INDEX idx_x ON t"
)
@testing.only_if("mssql>=11")
def test_index_reflection_colstore_nonclustered(
self, metadata, connection
):
t1 = Table(
"t",
metadata,
Column("id", Integer),
Column("x", types.String(20)),
Column("y", types.Integer),
)
Index("idx_x", t1.c.x, mssql_clustered=False, mssql_columnstore=True)
Index("idx_y", t1.c.y)
metadata.create_all(connection)
ind = testing.db.dialect.get_indexes(connection, "t", None)
for ix in ind:
is_false(ix["dialect_options"]["mssql_clustered"])
if ix["name"] == "idx_x":
is_true(ix["dialect_options"]["mssql_columnstore"])
eq_(ix["dialect_options"]["mssql_include"], [])
eq_(ix["column_names"], ["x"])
else:
is_false("mssql_columnstore" in ix["dialect_options"])
t2 = Table("t", MetaData(), autoload_with=connection)
idx = list(sorted(t2.indexes, key=lambda idx: idx.name))[0]
self.assert_compile(
CreateIndex(idx),
"CREATE NONCLUSTERED COLUMNSTORE INDEX idx_x ON t (x)",
)
@testing.only_if("mssql>=11")
def test_index_reflection_colstore_nonclustered_none(
self, metadata, connection
):
t1 = Table(
"t",
metadata,
Column("id", Integer),
Column("x", types.String(20)),
Column("y", types.Integer),
)
Index("idx_x", t1.c.x, mssql_columnstore=True)
Index("idx_y", t1.c.y)
metadata.create_all(connection)
ind = testing.db.dialect.get_indexes(connection, "t", None)
for ix in ind:
is_false(ix["dialect_options"]["mssql_clustered"])
if ix["name"] == "idx_x":
is_true(ix["dialect_options"]["mssql_columnstore"])
eq_(ix["dialect_options"]["mssql_include"], [])
eq_(ix["column_names"], ["x"])
else:
is_false("mssql_columnstore" in ix["dialect_options"])
t2 = Table("t", MetaData(), autoload_with=connection)
idx = list(sorted(t2.indexes, key=lambda idx: idx.name))[0]
self.assert_compile(
CreateIndex(idx),
"CREATE NONCLUSTERED COLUMNSTORE INDEX idx_x ON t (x)",
)
@testing.only_if("mssql>=11")
def test_index_reflection_colstore_nonclustered_multicol(
self, metadata, connection
):
t1 = Table(
"t",
metadata,
Column("id", Integer),
Column("x", types.String(20)),
Column("y", types.Integer),
)
Index(
"idx_xid",
t1.c.x,
t1.c.id,
mssql_clustered=False,
mssql_columnstore=True,
)
Index("idx_y", t1.c.y)
metadata.create_all(connection)
ind = testing.db.dialect.get_indexes(connection, "t", None)
for ix in ind:
is_false(ix["dialect_options"]["mssql_clustered"])
if ix["name"] == "idx_xid":
is_true(ix["dialect_options"]["mssql_columnstore"])
eq_(ix["dialect_options"]["mssql_include"], [])
eq_(ix["column_names"], ["x", "id"])
else:
is_false("mssql_columnstore" in ix["dialect_options"])
t2 = Table("t", MetaData(), autoload_with=connection)
idx = list(sorted(t2.indexes, key=lambda idx: idx.name))[0]
self.assert_compile(
CreateIndex(idx),
"CREATE NONCLUSTERED COLUMNSTORE INDEX idx_xid ON t (x, id)",
)
def test_primary_key_reflection_clustered(self, metadata, connection):
"""
A primary key will be clustered by default if no other clustered index
exists.
When reflected back, mssql_clustered=True should be present.
"""
t1 = Table(
"t",
metadata,
Column("id", Integer),
Column("x", types.String(20)),
Column("y", types.Integer),
)
PrimaryKeyConstraint(t1.c.id, name="pk_t")
metadata.create_all(connection)
pk_reflect = testing.db.dialect.get_pk_constraint(
connection, "t", None
)
assert pk_reflect["dialect_options"]["mssql_clustered"] == True
def test_primary_key_reflection_nonclustered(self, metadata, connection):
"""
Nonclustered primary key should include mssql_clustered=False
when reflected back
"""
t1 = Table(
"t",
metadata,
Column("id", Integer),
Column("x", types.String(20)),
Column("y", types.Integer),
)
PrimaryKeyConstraint(t1.c.id, name="pk_t", mssql_clustered=False)
metadata.create_all(connection)
pk_reflect = testing.db.dialect.get_pk_constraint(
connection, "t", None
)
assert pk_reflect["dialect_options"]["mssql_clustered"] == False
def test_max_ident_in_varchar_not_present(self, metadata, connection):
"""test [ticket:3504].
Here we are testing not just that the "max" token comes back
as None, but also that these types accept "max" as the value
of "length" on construction, which isn't a directly documented
pattern however is likely in common use.
"""
Table(
"t",
metadata,
Column("t1", types.String),
Column("t2", types.Text("max")),
Column("t3", types.Text("max")),
Column("t4", types.LargeBinary("max")),
Column("t5", types.VARBINARY("max")),
)
metadata.create_all(connection)
for col in inspect(connection).get_columns("t"):
is_(col["type"].length, None)
in_("max", str(col["type"].compile(dialect=connection.dialect)))
@testing.fixture
def comment_table(self, metadata):
Table(
"tbl_with_comments",
metadata,
Column(
"id",
types.Integer,
primary_key=True,
comment="pk comment 🔑",
),
Column("no_comment", types.Integer),
Column(
"has_comment",
types.String(20),
comment="has the comment § méil 📧",
),
comment="table comment çòé 🐍",
)
metadata.create_all(testing.db)
def test_comments(self, connection, comment_table):
insp = inspect(connection)
eq_(
insp.get_table_comment("tbl_with_comments"),
{"text": "table comment çòé 🐍"},
)
cols = {
col["name"]: col["comment"]
for col in insp.get_columns("tbl_with_comments")
}
eq_(
cols,
{
"id": "pk comment 🔑",
"no_comment": None,
"has_comment": "has the comment § méil 📧",
},
)
def test_comments_not_supported(self, testing_engine, comment_table):
eng = testing_engine(options={"supports_comments": False})
insp = inspect(eng)
with expect_raises_message(
NotImplementedError,
"Can't get table comments on current SQL Server version in use",
):
insp.get_table_comment("tbl_with_comments")
# currently, column comments still reflect normally since we
# aren't using an fn/sp for that
cols = {
col["name"]: col["comment"]
for col in insp.get_columns("tbl_with_comments")
}
eq_(
cols,
{
"id": "pk comment 🔑",
"no_comment": None,
"has_comment": "has the comment § méil 📧",
},
)
def test_comments_with_dropped_column(self, metadata, connection):
"""test issue #12654"""
Table(
"tbl_with_comments",
metadata,
Column(
"id", types.Integer, primary_key=True, comment="pk comment"
),
Column("foobar", Integer, comment="comment_foobar"),
Column("foo", Integer, comment="comment_foo"),
Column(
"bar",
Integer,
comment="comment_bar",
),
)
metadata.create_all(connection)
insp = inspect(connection)
eq_(
{
c["name"]: c["comment"]
for c in insp.get_columns("tbl_with_comments")
},
{
"id": "pk comment",
"foobar": "comment_foobar",
"foo": "comment_foo",
"bar": "comment_bar",
},
)
connection.exec_driver_sql(
"ALTER TABLE [tbl_with_comments] DROP COLUMN [foobar]"
)
insp = inspect(connection)
eq_(
{
c["name"]: c["comment"]
for c in insp.get_columns("tbl_with_comments")
},
{
"id": "pk comment",
"foo": "comment_foo",
"bar": "comment_bar",
},
)
class InfoCoerceUnicodeTest(fixtures.TestBase, AssertsCompiledSQL):
def test_info_unicode_cast_no_2000(self):
dialect = mssql.dialect()
dialect.server_version_info = base.MS_2000_VERSION
stmt = tables.c.table_name == "somename"
self.assert_compile(
stmt,
"[INFORMATION_SCHEMA].[TABLES].[TABLE_NAME] = :table_name_1",
dialect=dialect,
)
def test_info_unicode_cast(self):
dialect = mssql.dialect()
dialect.server_version_info = base.MS_2005_VERSION
stmt = tables.c.table_name == "somename"
self.assert_compile(
stmt,
"[INFORMATION_SCHEMA].[TABLES].[TABLE_NAME] = "
"CAST(:table_name_1 AS NVARCHAR(max))",
dialect=dialect,
)
class ReflectHugeViewTest(fixtures.TablesTest):
__only_on__ = "mssql"
__backend__ = True
# crashes on freetds 0.91, not worth it
__skip_if__ = (lambda: testing.requires.mssql_freetds.enabled,)
@classmethod
def define_tables(cls, metadata):
col_num = 150
t = Table(
"base_table",
metadata,
*[
Column("long_named_column_number_%d" % i, Integer)
for i in range(col_num)
],
)
cls.view_str = view_str = (
"CREATE VIEW huge_named_view AS SELECT %s FROM base_table"
% (
",".join(
"long_named_column_number_%d" % i for i in range(col_num)
)
)
)
assert len(view_str) > 4000
event.listen(t, "after_create", DDL(view_str))
event.listen(t, "before_drop", DDL("DROP VIEW huge_named_view"))
def test_inspect_view_definition(self):
inspector = inspect(testing.db)
view_def = inspector.get_view_definition("huge_named_view")
eq_(view_def, self.view_str)
class OwnerPlusDBTest(fixtures.TestBase):
def test_default_schema_name_not_interpreted_as_tokenized(self):
dialect = mssql.dialect()
dialect.server_version_info = base.MS_2014_VERSION
mock_connection = mock.Mock(scalar=lambda sql: "Jonah.The.Whale")
schema_name = dialect._get_default_schema_name(mock_connection)
eq_(schema_name, "Jonah.The.Whale")
eq_(
base._owner_plus_db(dialect, schema_name),
(None, "Jonah.The.Whale"),
)
def test_owner_database_pairs_dont_use_for_same_db(self):
dialect = mssql.dialect()
identifier = "my_db.some_schema"
schema, owner = base._owner_plus_db(dialect, identifier)
mock_connection = mock.Mock(
dialect=dialect,
exec_driver_sql=mock.Mock(
return_value=mock.Mock(scalar=mock.Mock(return_value="my_db"))
),
)
mock_lambda = mock.Mock()
base._switch_db(schema, mock_connection, mock_lambda, "x", y="bar")
eq_(
mock_connection.mock_calls,
[mock.call.exec_driver_sql("select db_name()")],
)
eq_(
mock_connection.exec_driver_sql.return_value.mock_calls,
[mock.call.scalar()],
),
eq_(mock_lambda.mock_calls, [mock.call("x", y="bar")])
def test_owner_database_pairs_switch_for_different_db(self):
dialect = mssql.dialect()
identifier = "my_other_db.some_schema"
schema, owner = base._owner_plus_db(dialect, identifier)
mock_connection = mock.Mock(
dialect=dialect,
exec_driver_sql=mock.Mock(
return_value=mock.Mock(scalar=mock.Mock(return_value="my_db"))
),
)
mock_lambda = mock.Mock()
base._switch_db(schema, mock_connection, mock_lambda, "x", y="bar")
eq_(
mock_connection.mock_calls,
[
mock.call.exec_driver_sql("select db_name()"),
mock.call.exec_driver_sql("use my_other_db"),
mock.call.exec_driver_sql("use my_db"),
],
eq_(
mock_connection.exec_driver_sql.return_value.mock_calls,
[mock.call.scalar()],
),
)
eq_(mock_lambda.mock_calls, [mock.call("x", y="bar")])
@testing.combinations(
("foo", None, "foo", "use foo"),
("foo.bar", "foo", "bar", "use foo"),
("Foo.Bar", "Foo", "Bar", "use [Foo]"),
("[Foo.Bar]", None, "Foo.Bar", "use [Foo.Bar]"),
("[Foo.Bar].[bat]", "Foo.Bar", "bat", "use [Foo.Bar]"),
(
"[foo].]do something; select [foo",
"foo",
"do something; select foo",
"use foo",
),
(
"something; select [foo].bar",
"something; select foo",
"bar",
"use [something; select foo]",
),
(
"[abc].[def].[efg].[hij]",
"[abc].[def].[efg]",
"hij",
"use [abc].[def].[efg]",
),
("abc.def.efg.hij", "abc.def.efg", "hij", "use [abc.def.efg]"),
)
def test_owner_database_pairs(
self, identifier, expected_schema, expected_owner, use_stmt
):
dialect = mssql.dialect()
schema, owner = base._owner_plus_db(dialect, identifier)
eq_(owner, expected_owner)
eq_(schema, expected_schema)
mock_connection = mock.Mock(
dialect=dialect,
exec_driver_sql=mock.Mock(
return_value=mock.Mock(
scalar=mock.Mock(return_value="Some Database")
)
),
)
mock_lambda = mock.Mock()
base._switch_db(schema, mock_connection, mock_lambda, "x", y="bar")
if schema is None:
eq_(mock_connection.mock_calls, [])
else:
eq_(
mock_connection.mock_calls,
[
mock.call.exec_driver_sql("select db_name()"),
mock.call.exec_driver_sql(use_stmt),
mock.call.exec_driver_sql("use [Some Database]"),
],
)
eq_(
mock_connection.exec_driver_sql.return_value.mock_calls,
[mock.call.scalar()],
)
eq_(mock_lambda.mock_calls, [mock.call("x", y="bar")])
class IdentityReflectionTest(fixtures.TablesTest):
__only_on__ = "mssql"
__backend__ = True
__requires__ = ("identity_columns",)
@classmethod
def define_tables(cls, metadata):
for i, col in enumerate(
[
Column(
"id1",
Integer,
Identity(
always=True,
start=2,
increment=3,
minvalue=-2,
maxvalue=42,
cycle=True,
cache=4,
),
),
Column("id2", Integer, Identity()),
Column(
"id3",
sqltypes.BigInteger,
Identity(start=-9223372036854775808),
),
Column("id4", sqltypes.SmallInteger, Identity()),
Column("id5", sqltypes.Numeric, Identity()),
]
):
Table("t%s" % i, metadata, col)
def test_reflect_identity(self, connection):
insp = inspect(connection)
cols = []
for t in self.tables_test_metadata.tables.keys():
cols.extend(insp.get_columns(t))
for col in cols:
is_true("dialect_options" not in col)
is_true("identity" in col)
if col["name"] == "id1":
eq_(col["identity"], {"start": 2, "increment": 3})
elif col["name"] == "id2":
eq_(col["identity"], {"start": 1, "increment": 1})
eq_(type(col["identity"]["start"]), int)
eq_(type(col["identity"]["increment"]), int)
elif col["name"] == "id3":
eq_(
col["identity"],
{"start": -9223372036854775808, "increment": 1},
)
eq_(type(col["identity"]["start"]), int)
eq_(type(col["identity"]["increment"]), int)
elif col["name"] == "id4":
eq_(col["identity"], {"start": 1, "increment": 1})
eq_(type(col["identity"]["start"]), int)
eq_(type(col["identity"]["increment"]), int)
elif col["name"] == "id5":
eq_(col["identity"], {"start": 1, "increment": 1})
eq_(type(col["identity"]["start"]), decimal.Decimal)
eq_(type(col["identity"]["increment"]), decimal.Decimal)
@testing.requires.views
def test_reflect_views(self, connection):
connection.exec_driver_sql("CREATE VIEW view1 AS SELECT * FROM t1")
insp = inspect(connection)
for col in insp.get_columns("view1"):
is_true("dialect_options" not in col)
is_true("identity" in col)
eq_(col["identity"], {})
|