diff --git a/src/main/java/de/avatic/lcc/database/dialect/MSSQLDialectProvider.java b/src/main/java/de/avatic/lcc/database/dialect/MSSQLDialectProvider.java
index f5cdacd..100edf3 100644
--- a/src/main/java/de/avatic/lcc/database/dialect/MSSQLDialectProvider.java
+++ b/src/main/java/de/avatic/lcc/database/dialect/MSSQLDialectProvider.java
@@ -148,49 +148,32 @@ public class MSSQLDialectProvider implements SqlDialectProvider {
);
}
- /**
- * Builds MSSQL INSERT with IF NOT EXISTS check.
- *
- *
MSSQL doesn't have INSERT IGNORE, so we use IF NOT EXISTS.
- *
- * Example generated SQL:
- *
- * IF NOT EXISTS (SELECT 1 FROM table WHERE key1 = ? AND key2 = ?)
- * INSERT INTO table (col1, col2, col3) VALUES (?, ?, ?)
- *
- *
- * @param tableName target table name
- * @param columns columns to insert
- * @param uniqueColumns columns to check for existence
- * @return MSSQL INSERT with IF NOT EXISTS
- */
@Override
public String buildInsertIgnoreStatement(
String tableName,
List columns,
List uniqueColumns
) {
- if (tableName == null || columns.isEmpty() || uniqueColumns.isEmpty()) {
- throw new IllegalArgumentException("tableName, columns, and uniqueColumns must not be empty");
- }
-
- String whereClause = uniqueColumns.stream()
- .map(col -> col + " = ?")
- .collect(Collectors.joining(" AND "));
-
String columnList = String.join(", ", columns);
- String placeholders = columns.stream()
- .map(col -> "?")
+ String placeholders = columns.stream().map(c -> "?").collect(Collectors.joining(", "));
+ String uniqueCondition = uniqueColumns.stream()
+ .map(c -> String.format("target.%s = source.%s", c, c))
+ .collect(Collectors.joining(" AND "));
+ String sourceColumns = columns.stream()
+ .map(c -> String.format("source.%s", c))
.collect(Collectors.joining(", "));
return String.format(
- "IF NOT EXISTS (SELECT 1 FROM %s WHERE %s) " +
- "INSERT INTO %s (%s) VALUES (%s)",
- tableName,
- whereClause,
+ "MERGE INTO %s AS target " +
+ "USING (SELECT %s) AS source (%s) " +
+ "ON %s " +
+ "WHEN NOT MATCHED THEN INSERT (%s) VALUES (%s);",
tableName,
+ placeholders,
columnList,
- placeholders
+ uniqueCondition,
+ columnList,
+ sourceColumns
);
}
diff --git a/src/main/java/de/avatic/lcc/repositories/country/CountryPropertyRepository.java b/src/main/java/de/avatic/lcc/repositories/country/CountryPropertyRepository.java
index bd91a78..cd0f6c2 100644
--- a/src/main/java/de/avatic/lcc/repositories/country/CountryPropertyRepository.java
+++ b/src/main/java/de/avatic/lcc/repositories/country/CountryPropertyRepository.java
@@ -150,7 +150,6 @@ public class CountryPropertyRepository {
type.external_mapping_id as externalMappingId,
type.validation_rule as validationRule,
type.is_required as is_required,
- type.is_required as is_required,
type.description as description,
type.property_group as propertyGroup,
type.sequence_number as sequenceNumber,
@@ -159,7 +158,8 @@ public class CountryPropertyRepository {
FROM country_property_type AS type
LEFT JOIN country_property AS cp ON cp.country_property_type_id = type.id AND cp.country_id = ?
LEFT JOIN property_set AS ps ON ps.id = cp.property_set_id AND ps.state IN ('DRAFT', 'VALID')
- GROUP BY type.id, type.name, type.data_type, type.external_mapping_id, type.validation_rule
+ GROUP BY type.id, type.name, type.data_type, type.external_mapping_id, type.validation_rule,
+ type.is_required, type.description, type.property_group, type.sequence_number
HAVING MAX(CASE WHEN ps.state = 'DRAFT' THEN cp.property_value END) IS NOT NULL
OR MAX(CASE WHEN ps.state = 'VALID' THEN cp.property_value END) IS NOT NULL;
""";
diff --git a/src/test/java/de/avatic/lcc/repositories/country/CountryPropertyRepositoryIntegrationTest.java b/src/test/java/de/avatic/lcc/repositories/country/CountryPropertyRepositoryIntegrationTest.java
index 19d858f..3ca75b3 100644
--- a/src/test/java/de/avatic/lcc/repositories/country/CountryPropertyRepositoryIntegrationTest.java
+++ b/src/test/java/de/avatic/lcc/repositories/country/CountryPropertyRepositoryIntegrationTest.java
@@ -142,9 +142,6 @@ class CountryPropertyRepositoryIntegrationTest extends AbstractRepositoryIntegra
@Test
void testListPropertiesByCountryId() {
- // Skip on MSSQL - listPropertiesByCountryId() has incomplete GROUP BY clause (missing is_required, description, property_group, sequence_number)
- org.junit.Assume.assumeTrue("Skipping listPropertiesByCountryId on MSSQL (SQL GROUP BY bug in repository)", isMysql());
-
// Given: Create properties for country
createTestCountryProperty(testDraftSetId, testCountryId, testPropertyTypeId, "45");
createTestCountryProperty(testValidSetId, testCountryId, testPropertyTypeId, "30");
@@ -188,9 +185,6 @@ class CountryPropertyRepositoryIntegrationTest extends AbstractRepositoryIntegra
@Test
void testFillDraft() {
- // Skip on MSSQL - buildInsertIgnoreStatement needs fix for parameter ordering in IF NOT EXISTS pattern
- org.junit.Assume.assumeTrue("Skipping fillDraft on MSSQL (known issue with INSERT IGNORE)", isMysql());
-
// Given: Create properties in valid set for multiple property types
Integer propertyType2 = getPropertyTypeId(CountryPropertyMappingId.WAGE.name());
createTestCountryProperty(testValidSetId, testCountryId, testPropertyTypeId, "30");
diff --git a/src/test/java/de/avatic/lcc/repositories/properties/PropertyRepositoryIntegrationTest.java b/src/test/java/de/avatic/lcc/repositories/properties/PropertyRepositoryIntegrationTest.java
index c61fe02..885b121 100644
--- a/src/test/java/de/avatic/lcc/repositories/properties/PropertyRepositoryIntegrationTest.java
+++ b/src/test/java/de/avatic/lcc/repositories/properties/PropertyRepositoryIntegrationTest.java
@@ -189,9 +189,6 @@ class PropertyRepositoryIntegrationTest extends AbstractRepositoryIntegrationTes
@Test
void testFillDraft() {
- // Skip on MSSQL - buildInsertIgnoreStatement needs fix for parameter ordering in IF NOT EXISTS pattern
- org.junit.Assume.assumeTrue("Skipping fillDraft on MSSQL (known issue with INSERT IGNORE)", isMysql());
-
// Given: Create properties in valid set
Integer propertyType2 = getPropertyTypeId(SystemPropertyMappingId.WORKDAYS.name());
createTestProperty(testValidSetId, testPropertyTypeId, "30");
@@ -220,9 +217,6 @@ class PropertyRepositoryIntegrationTest extends AbstractRepositoryIntegrationTes
@Test
void testFillDraftIgnoresDuplicates() {
- // Skip on MSSQL - buildInsertIgnoreStatement needs fix for parameter ordering in IF NOT EXISTS pattern
- org.junit.Assume.assumeTrue("Skipping fillDraft on MSSQL (known issue with INSERT IGNORE)", isMysql());
-
// Given: Create property in valid set
createTestProperty(testValidSetId, testPropertyTypeId, "30");
diff --git a/src/test/java/de/avatic/lcc/repositories/users/AppRepositoryIntegrationTest.java b/src/test/java/de/avatic/lcc/repositories/users/AppRepositoryIntegrationTest.java
index 983c60b..d535e99 100644
--- a/src/test/java/de/avatic/lcc/repositories/users/AppRepositoryIntegrationTest.java
+++ b/src/test/java/de/avatic/lcc/repositories/users/AppRepositoryIntegrationTest.java
@@ -163,9 +163,6 @@ class AppRepositoryIntegrationTest extends AbstractRepositoryIntegrationTest {
@Test
void testAppWithGroups() {
- // Skip on MSSQL - buildInsertIgnoreStatement needs fix for parameter ordering
- org.junit.Assume.assumeTrue("Skipping app-group mapping on MSSQL (known issue with INSERT IGNORE)", isMysql());
-
// Given: App with groups
App app = createTestApp("App with Groups", "grouped_client", "grouped_secret");
Group group1 = new Group();
@@ -191,9 +188,6 @@ class AppRepositoryIntegrationTest extends AbstractRepositoryIntegrationTest {
@Test
void testUpdateAppGroups() {
- // Skip on MSSQL - buildInsertIgnoreStatement needs fix for parameter ordering
- org.junit.Assume.assumeTrue("Skipping app-group mapping on MSSQL (known issue with INSERT IGNORE)", isMysql());
-
// Given: App with one group
App app = createTestApp("Group Update Test", "group_update_client", "group_update_secret");
Group group1 = new Group();
@@ -217,9 +211,6 @@ class AppRepositoryIntegrationTest extends AbstractRepositoryIntegrationTest {
@Test
void testDeleteAppCascadesGroupMappings() {
- // Skip on MSSQL - buildInsertIgnoreStatement needs fix for parameter ordering
- org.junit.Assume.assumeTrue("Skipping app-group mapping on MSSQL (known issue with INSERT IGNORE)", isMysql());
-
// Given: App with groups
App app = createTestApp("Cascade Delete Test", "cascade_client", "cascade_secret");
Group group1 = new Group();