diff --git a/typo3/sysext/core/Classes/Database/Query/Expression/ExpressionBuilder.php b/typo3/sysext/core/Classes/Database/Query/Expression/ExpressionBuilder.php
index 545b66d3fb954c5d0870cb0f3f9c7c62220f1a4b..9e2edb45f783463de2916278da90ec41da078a8a 100644
--- a/typo3/sysext/core/Classes/Database/Query/Expression/ExpressionBuilder.php
+++ b/typo3/sysext/core/Classes/Database/Query/Expression/ExpressionBuilder.php
@@ -382,6 +382,119 @@ class ExpressionBuilder
         }
     }
 
+    /**
+     * Returns a comparison that can find a value in a list field (CSV) but is negated.
+     *
+     * @param string $fieldName The field name. Will be quoted according to database platform automatically.
+     * @param string $value Argument to be used in FIND_IN_SET() comparison. No automatic quoting/escaping is done.
+     * @param bool $isColumn Set when the value to compare is a column on a table to activate casting
+     * @return string
+     * @throws \InvalidArgumentException
+     * @throws \RuntimeException
+     */
+    public function notInSet(string $fieldName, string $value, bool $isColumn = false): string
+    {
+        if ($value === '') {
+            throw new \InvalidArgumentException(
+                'ExpressionBuilder::notInSet() can not be used with an empty string value.',
+                1627573099
+            );
+        }
+
+        if (strpos($value, ',') !== false) {
+            throw new \InvalidArgumentException(
+                'ExpressionBuilder::notInSet() can not be used with values that contain a comma (",").',
+                1627573100
+            );
+        }
+
+        switch ($this->connection->getDatabasePlatform()->getName()) {
+            case 'postgresql':
+            case 'pdo_postgresql':
+                return $this->comparison(
+                    $isColumn ? $value . '::text' : $this->literal($this->unquoteLiteral((string)$value)),
+                    self::NEQ,
+                    sprintf(
+                        'ALL(string_to_array(%s, %s))',
+                        $this->connection->quoteIdentifier($fieldName) . '::text',
+                        $this->literal(',')
+                    )
+                );
+            case 'oci8':
+            case 'pdo_oracle':
+                throw new \RuntimeException(
+                    'negative FIND_IN_SET support for database platform "Oracle" not yet implemented.',
+                    1627573101
+                );
+            case 'sqlsrv':
+            case 'pdo_sqlsrv':
+            case 'mssql':
+                // See unit and functional tests for details
+                if ($isColumn) {
+                    $expression = $this->andX(
+                        $this->neq($fieldName, $value),
+                        $this->notLike($fieldName, $value . ' + \',%\''),
+                        $this->notLike($fieldName, '\'%,\' + ' . $value),
+                        $this->notLike($fieldName, '\'%,\' + ' . $value . ' + \',%\'')
+                    );
+                } else {
+                    $likeEscapedValue = str_replace(
+                        ['[', '%'],
+                        ['[[]', '[%]'],
+                        $this->unquoteLiteral($value)
+                    );
+                    $expression = $this->andX(
+                        $this->neq($fieldName, $this->literal($this->unquoteLiteral((string)$value))),
+                        $this->notLike($fieldName, $this->literal($likeEscapedValue . ',%')),
+                        $this->notLike($fieldName, $this->literal('%,' . $likeEscapedValue)),
+                        $this->notLike($fieldName, $this->literal('%,' . $likeEscapedValue . ',%'))
+                    );
+                }
+                return (string)$expression;
+            case 'sqlite':
+            case 'sqlite3':
+            case 'pdo_sqlite':
+                if (strpos($value, ':') === 0 || $value === '?') {
+                    throw new \InvalidArgumentException(
+                        'ExpressionBuilder::inSet() for SQLite can not be used with placeholder arguments.',
+                        1627573103
+                    );
+                }
+                $comparison = sprintf(
+                    'instr(%s, %s) = 0',
+                    implode(
+                        '||',
+                        [
+                            $this->literal(','),
+                            $this->connection->quoteIdentifier($fieldName),
+                            $this->literal(','),
+                        ]
+                    ),
+                    $isColumn ?
+                        implode(
+                            '||',
+                            [
+                                $this->literal(','),
+                                // do not explicitly quote value as it is expected to be
+                                // quoted by the caller
+                                'cast(' . $value . ' as text)',
+                                $this->literal(','),
+                            ]
+                        )
+                        : $this->literal(
+                            ',' . $this->unquoteLiteral($value) . ','
+                        )
+                );
+                return $comparison;
+            default:
+                return sprintf(
+                    'NOT FIND_IN_SET(%s, %s)',
+                    $value,
+                    $this->connection->quoteIdentifier($fieldName)
+                );
+        }
+    }
+
     /**
      * Creates a bitwise AND expression with the given arguments.
      *
diff --git a/typo3/sysext/core/Documentation/Changelog/master/Feature-84115-DoctrineDBAL-NotInSetForExpressions.rst b/typo3/sysext/core/Documentation/Changelog/master/Feature-84115-DoctrineDBAL-NotInSetForExpressions.rst
new file mode 100644
index 0000000000000000000000000000000000000000..9b9ab0ebc1b78ec710ee4b6da5c8d0fe75907781
--- /dev/null
+++ b/typo3/sysext/core/Documentation/Changelog/master/Feature-84115-DoctrineDBAL-NotInSetForExpressions.rst
@@ -0,0 +1,50 @@
+.. include:: ../../Includes.txt
+
+============================================================
+Feature: #84115 - Doctrine DBAL - notInSet() for expressions
+============================================================
+
+See :issue:`84115`
+
+Description
+===========
+
+TYPO3's Database Abstraction Layer supports a wide range of
+cross-RDBMS-functionality to limit SELECT statements via
+the ExpressionBuilder.
+
+When using the ExpressionBuilder for comma-separated lists,
+the call `inSet()` can be used to detect database rows
+which include a value in a comma-separated list, such as
+`pages.fe_group` where the UIDs of allowed frontend user groups
+are stored.
+
+The method `notInSet()` has been added to TYPO3's DBAL ExpressionBuilder,
+which works as the opposite functionality:
+"Get all rows where a certain value is NOT in the list of comma-separated values".
+
+
+Impact
+======
+
+It is now possible to use `notInSet()` via Doctrine DBAL
+Expression Builder for SQLite, MySQL/MariaDB, PostgreSQL and MSSQL Backends.
+
+Example:
+
+    $queryBuilder = GeneralUtility::makeInstance(ConnectionPool::class)->getQueryBuilderForTable('fe_users');
+    $result = $queryBuilder
+        ->select('*')
+        ->from('fe_users')
+        ->where(
+            $queryBuilder->expr()->notInSet('usergroup', '5')
+        )
+        ->execute();
+
+This queries all frontend users which do not directly belong
+to usergroup of with uid "5".
+
+Please note that this functionality is for extension authors
+and their usage should be thought-through properly, as queries such as "Show me all results where the usergroup NO access to" isn't a use-case for `notInSet()`.
+
+.. index:: Database, ext:core
\ No newline at end of file
diff --git a/typo3/sysext/core/Tests/Functional/Database/Query/Expression/ExpressionBuilderTest.php b/typo3/sysext/core/Tests/Functional/Database/Query/Expression/ExpressionBuilderTest.php
index 9a963b070975e0e0875094c7f77178dae88a6541..b5e98afa85cdafe1e41fd4b01b3a91b56b031170 100644
--- a/typo3/sysext/core/Tests/Functional/Database/Query/Expression/ExpressionBuilderTest.php
+++ b/typo3/sysext/core/Tests/Functional/Database/Query/Expression/ExpressionBuilderTest.php
@@ -398,4 +398,280 @@ class ExpressionBuilderTest extends FunctionalTestCase
         ];
         self::assertEquals($expected, $result);
     }
+
+    /**
+     * notInSet tests, as they reverse the tests from above, only the count() logic is used to avoid too many
+     * result arrays to be defined.
+     */
+
+    /**
+     * @test
+     */
+    public function notInSetReturnsExpectedDataSetsWithColumn()
+    {
+        $this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
+        $queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
+        $result = $queryBuilder
+            ->select('uid', 'aCsvField')
+            ->from('tx_expressionbuildertest')
+            ->where(
+                $queryBuilder->expr()->notInSet('aCsvField', $queryBuilder->quoteIdentifier('aField'), true)
+            )
+            ->orderBy('uid')
+            ->execute()
+            ->fetchAllAssociative();
+        $expected = [
+            0 => [
+                'uid' => 5,
+                'aCsvField' => 'nomatch',
+            ],
+            1 => [
+                'uid' => 10,
+                'aCsvField' => '4',
+            ],
+            2 => [
+                'uid' => 15,
+                'aCsvField' => 'nowild%card',
+            ],
+            3 => [
+                'uid' => 16,
+                'aCsvField' => 'wild[card',
+            ],
+            4 => [
+                'uid' => 17,
+                'aCsvField' => 'wild[card,nowild[card',
+            ],
+            5 => [
+                'uid' => 18,
+                'aCsvField' => 'nowild[card,wild[card',
+            ],
+            6 => [
+                'uid' => 19,
+                'aCsvField' => 'nowild[card1,wild[card,nowild[card2',
+            ],
+            7 => [
+                'uid' => 20,
+                'aCsvField' => 'nowild[card',
+            ],
+            8 => [
+                'uid' => 21,
+                'aCsvField' => 'wild]card',
+            ],
+            9 => [
+                'uid' => 22,
+                'aCsvField' => 'wild]card,nowild]card',
+            ],
+            10 => [
+                'uid' => 23,
+                'aCsvField' => 'nowild]card,wild]card',
+            ],
+            11 => [
+                'uid' => 24,
+                'aCsvField' => 'nowild]card1,wild]card,nowild]card2',
+            ],
+            12 => [
+                'uid' => 25,
+                'aCsvField' => 'nowild]card',
+            ],
+            13 => [
+                'uid' => 26,
+                'aCsvField' => 'wild[]card',
+            ],
+            14 => [
+                'uid' => 27,
+                'aCsvField' => 'wild[]card,nowild[]card',
+            ],
+            15 => [
+                'uid' => 28,
+                'aCsvField' => 'nowild[]card,wild[]card',
+            ],
+            16 => [
+                'uid' => 29,
+                'aCsvField' => 'nowild[]card1,wild[]card,nowild[]card2',
+            ],
+            17 => [
+                'uid' => 30,
+                'aCsvField' => 'nowild[]card',
+            ],
+            18 => [
+                'uid' => 31,
+                'aCsvField' => 'wild[foo]card',
+            ],
+            19 => [
+                'uid' => 32,
+                'aCsvField' => 'wild[foo]card,nowild[foo]card',
+            ],
+            20 => [
+                'uid' => 33,
+                'aCsvField' => 'nowild[foo]card,wild[foo]card',
+            ],
+            21 => [
+                'uid' => 34,
+                'aCsvField' => 'nowild[foo]card1,wild[foo]card,nowild[foo]card2',
+            ],
+            22 => [
+                'uid' => 35,
+                'aCsvField' => 'nowild[foo]card',
+            ],
+            23 => [
+                'uid' => 36,
+                'aCsvField' => 'wild[%]card',
+            ],
+            24 => [
+                'uid' => 37,
+                'aCsvField' => 'wild[%]card,nowild[%]card',
+            ],
+            25 => [
+                'uid' => 38,
+                'aCsvField' => 'nowild[%]card,wild[%]card',
+            ],
+            26 => [
+                'uid' => 39,
+                'aCsvField' => 'nowild[%]card1,wild[%]card,nowild[%]card2',
+            ],
+            27 => [
+                'uid' => 40,
+                'aCsvField' => 'nowild[%]card',
+            ],
+        ];
+        self::assertEquals($expected, $result);
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetReturnsExpectedDataSets()
+    {
+        $this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
+        $queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
+        $queryBuilder
+            ->count('uid')
+            ->from('tx_expressionbuildertest');
+        // Count all rows
+        self::assertEquals(40, $queryBuilder->execute()->fetchOne());
+
+        // Count the ones not in set
+        $queryBuilder->where(
+            $queryBuilder->expr()->notInSet('aCsvField', $queryBuilder->expr()->literal('match')),
+        );
+        self::assertEquals(36, $queryBuilder->execute()->fetchOne());
+
+        // Count the ones in set
+        $queryBuilder->where(
+            $queryBuilder->expr()->inSet('aCsvField', $queryBuilder->expr()->literal('match')),
+        );
+        self::assertEquals(4, $queryBuilder->execute()->fetchOne());
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetReturnsExpectedDataSetsWithInts()
+    {
+        $this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
+        $queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
+        $queryBuilder
+            ->count('uid')
+            ->from('tx_expressionbuildertest')
+            ->where(
+                $queryBuilder->expr()->notInSet('aCsvField', (string)2)
+            );
+        self::assertEquals(36, $queryBuilder->execute()->fetchOne());
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetReturnsExpectedDataSetsIfValueContainsLikeWildcard()
+    {
+        $this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
+        $queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
+        $queryBuilder
+            ->count('uid')
+            ->from('tx_expressionbuildertest')
+            ->where(
+                $queryBuilder->expr()->notInSet('aCsvField', $queryBuilder->expr()->literal('wild%card'))
+            );
+        self::assertEquals(36, $queryBuilder->execute()->fetchOne());
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetReturnsExpectedDataSetsIfValueContainsBracket()
+    {
+        $this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
+        $queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
+        $queryBuilder
+            ->count('uid')
+            ->from('tx_expressionbuildertest')
+            ->where(
+                $queryBuilder->expr()->notInSet('aCsvField', $queryBuilder->expr()->literal('wild[card'))
+            );
+        self::assertEquals(36, $queryBuilder->execute()->fetchOne());
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetReturnsExpectedDataSetsIfValueContainsClosingBracket()
+    {
+        $this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
+        $queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
+        $queryBuilder
+            ->count('uid')
+            ->from('tx_expressionbuildertest')
+            ->where(
+                $queryBuilder->expr()->notInSet('aCsvField', $queryBuilder->expr()->literal('wild]card'))
+            );
+        self::assertEquals(36, $queryBuilder->execute()->fetchOne());
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetReturnsExpectedDataSetsIfValueContainsOpeningAndClosingBracket()
+    {
+        $this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
+        $queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
+        $queryBuilder
+            ->count('uid')
+            ->from('tx_expressionbuildertest')
+            ->where(
+                $queryBuilder->expr()->notInSet('aCsvField', $queryBuilder->expr()->literal('wild[]card'))
+            );
+        self::assertEquals(36, $queryBuilder->execute()->fetchOne());
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetReturnsExpectedDataSetsIfValueContainsBracketsAroundWord()
+    {
+        $this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
+        $queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
+        $queryBuilder
+            ->count('uid')
+            ->from('tx_expressionbuildertest')
+            ->where(
+                $queryBuilder->expr()->notInSet('aCsvField', $queryBuilder->expr()->literal('wild[foo]card'))
+            );
+        self::assertEquals(36, $queryBuilder->execute()->fetchOne());
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetReturnsExpectedDataSetsIfValueContainsBracketsAroundLikeWildcard()
+    {
+        $this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
+        $queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
+        $queryBuilder
+            ->count('uid')
+            ->from('tx_expressionbuildertest')
+            ->where(
+                $queryBuilder->expr()->notInSet('aCsvField', $queryBuilder->expr()->literal('wild[%]card'))
+            );
+        self::assertEquals(36, $queryBuilder->execute()->fetchOne());
+    }
 }
diff --git a/typo3/sysext/core/Tests/Unit/Database/Query/Expression/ExpressionBuilderTest.php b/typo3/sysext/core/Tests/Unit/Database/Query/Expression/ExpressionBuilderTest.php
index 2d7b9e594aa1ad1246d42a1293e43c6c63dfedaa..f0b07501deaede9d4c102ddd28d6db16adb49400 100644
--- a/typo3/sysext/core/Tests/Unit/Database/Query/Expression/ExpressionBuilderTest.php
+++ b/typo3/sysext/core/Tests/Unit/Database/Query/Expression/ExpressionBuilderTest.php
@@ -373,7 +373,7 @@ class ExpressionBuilderTest extends UnitTestCase
 
         $this->connectionProphet->getDatabasePlatform()->willReturn($databasePlatform->reveal());
 
-        $this->expectException('InvalidArgumentException');
+        $this->expectException(\InvalidArgumentException::class);
         $this->expectExceptionCode(1476029421);
 
         $this->subject->inSet('aField', '?');
@@ -390,7 +390,7 @@ class ExpressionBuilderTest extends UnitTestCase
 
         $this->connectionProphet->getDatabasePlatform()->willReturn($databasePlatform->reveal());
 
-        $this->expectException('InvalidArgumentException');
+        $this->expectException(\InvalidArgumentException::class);
         $this->expectExceptionCode(1476029421);
 
         $this->subject->inSet('aField', ':dcValue1');
@@ -420,6 +420,190 @@ class ExpressionBuilderTest extends UnitTestCase
         self::assertSame("([aField] = '1') OR ([aField] LIKE '1,%') OR ([aField] LIKE '%,1') OR ([aField] LIKE '%,1,%')", $result);
     }
 
+    /**
+     * @test
+     */
+    public function notInSetThrowsExceptionWithEmptyValue()
+    {
+        $this->expectException(\InvalidArgumentException::class);
+        $this->expectExceptionCode(1627573099);
+        $this->subject->notInSet('aField', '');
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetThrowsExceptionWithInvalidValue()
+    {
+        $this->expectException(\InvalidArgumentException::class);
+        $this->expectExceptionCode(1627573100);
+        $this->subject->notInSet('aField', 'an,Invalid,Value');
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetForMySQL()
+    {
+        $databasePlatform = $this->prophesize(MockPlatform::class);
+        $databasePlatform->getName()->willReturn('mysql');
+
+        $this->connectionProphet->quoteIdentifier(Argument::cetera())->will(function ($args) {
+            return '`' . $args[0] . '`';
+        });
+
+        $this->connectionProphet->getDatabasePlatform()->willReturn($databasePlatform->reveal());
+
+        $result = $this->subject->notInSet('aField', "'1'");
+
+        self::assertSame('NOT FIND_IN_SET(\'1\', `aField`)', $result);
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetForPostgreSQL()
+    {
+        $databasePlatform = $this->prophesize(MockPlatform::class);
+        $databasePlatform->getName()->willReturn('postgresql');
+        $databasePlatform->getStringLiteralQuoteCharacter()->willReturn('"');
+
+        $this->connectionProphet->quote(',', Argument::cetera())->shouldBeCalled()->willReturn("','");
+        $this->connectionProphet->quote("'1'", null)->shouldBeCalled()->willReturn("'1'");
+        $this->connectionProphet->quoteIdentifier(Argument::cetera())->will(function ($args) {
+            return '"' . $args[0] . '"';
+        });
+
+        $this->connectionProphet->getDatabasePlatform()->willReturn($databasePlatform->reveal());
+
+        $result = $this->subject->notInSet('aField', "'1'");
+
+        self::assertSame('\'1\' <> ALL(string_to_array("aField"::text, \',\'))', $result);
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetForPostgreSQLWithColumn()
+    {
+        $databasePlatform = $this->prophesize(MockPlatform::class);
+        $databasePlatform->getName()->willReturn('postgresql');
+
+        $this->connectionProphet->quote(',', Argument::cetera())->shouldBeCalled()->willReturn("','");
+        $this->connectionProphet->quoteIdentifier(Argument::cetera())->will(function ($args) {
+            return '"' . $args[0] . '"';
+        });
+
+        $this->connectionProphet->getDatabasePlatform()->willReturn($databasePlatform->reveal());
+
+        $result = $this->subject->notInSet('aField', '"testtable"."uid"', true);
+
+        self::assertSame('"testtable"."uid"::text <> ALL(string_to_array("aField"::text, \',\'))', $result);
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetForSQLite()
+    {
+        $databasePlatform = $this->prophesize(MockPlatform::class);
+        $databasePlatform->getName()->willReturn('sqlite');
+        $databasePlatform->getStringLiteralQuoteCharacter()->willReturn("'");
+
+        $this->connectionProphet->quote(',', Argument::cetera())->shouldBeCalled()->willReturn("','");
+        $this->connectionProphet->quote(',1,', Argument::cetera())->shouldBeCalled()->willReturn("'%,1,%'");
+        $this->connectionProphet->quoteIdentifier(Argument::cetera())->will(function ($args) {
+            return '"' . $args[0] . '"';
+        });
+
+        $this->connectionProphet->getDatabasePlatform()->willReturn($databasePlatform->reveal());
+
+        $result = $this->subject->notInSet('aField', "'1'");
+
+        self::assertSame('instr(\',\'||"aField"||\',\', \'%,1,%\') = 0', $result);
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetForSQLiteWithQuoteCharactersInValue()
+    {
+        $databasePlatform = $this->prophesize(MockPlatform::class);
+        $databasePlatform->getName()->willReturn('sqlite');
+        $databasePlatform->getStringLiteralQuoteCharacter()->willReturn("'");
+
+        $this->connectionProphet->quote(',', Argument::cetera())->shouldBeCalled()->willReturn("','");
+        $this->connectionProphet->quote(',\'Some\'Value,', Argument::cetera())->shouldBeCalled()
+            ->willReturn("',''Some''Value,'");
+        $this->connectionProphet->quoteIdentifier(Argument::cetera())->will(function ($args) {
+            return '"' . $args[0] . '"';
+        });
+
+        $this->connectionProphet->getDatabasePlatform()->willReturn($databasePlatform->reveal());
+
+        $result = $this->subject->notInSet('aField', "'''Some''Value'");
+
+        self::assertSame('instr(\',\'||"aField"||\',\', \',\'\'Some\'\'Value,\') = 0', $result);
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetForSQLiteThrowsExceptionOnPositionalPlaceholder()
+    {
+        $databasePlatform = $this->prophesize(MockPlatform::class);
+        $databasePlatform->getName()->willReturn('sqlite');
+        $databasePlatform->getStringLiteralQuoteCharacter()->willReturn("'");
+
+        $this->connectionProphet->getDatabasePlatform()->willReturn($databasePlatform->reveal());
+
+        $this->expectException(\InvalidArgumentException::class);
+        $this->expectExceptionCode(1627573103);
+
+        $this->subject->notInSet('aField', '?');
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetForSQLiteThrowsExceptionOnNamedPlaceholder()
+    {
+        $databasePlatform = $this->prophesize(MockPlatform::class);
+        $databasePlatform->getName()->willReturn('sqlite');
+        $databasePlatform->getStringLiteralQuoteCharacter()->willReturn("'");
+
+        $this->connectionProphet->getDatabasePlatform()->willReturn($databasePlatform->reveal());
+
+        $this->expectException(\InvalidArgumentException::class);
+        $this->expectExceptionCode(1476029421);
+
+        $this->subject->inSet('aField', ':dcValue1');
+    }
+
+    /**
+     * @test
+     */
+    public function notInSetForMssql()
+    {
+        $databasePlatform = $this->prophesize(MockPlatform::class);
+        $databasePlatform->getName()->willReturn('mssql');
+        $databasePlatform->getStringLiteralQuoteCharacter()->willReturn('\'');
+
+        $this->connectionProphet->quote('1', null)->shouldBeCalled()->willReturn("'1'");
+        $this->connectionProphet->quote('1,%', null)->shouldBeCalled()->willReturn("'1,%'");
+        $this->connectionProphet->quote('%,1', null)->shouldBeCalled()->willReturn("'%,1'");
+        $this->connectionProphet->quote('%,1,%', null)->shouldBeCalled()->willReturn("'%,1,%'");
+        $this->connectionProphet->quoteIdentifier(Argument::cetera())->will(function ($args) {
+            return '[' . $args[0] . ']';
+        });
+
+        $this->connectionProphet->getDatabasePlatform()->willReturn($databasePlatform->reveal());
+
+        $result = $this->subject->inSet('aField', "'1'");
+
+        self::assertSame("([aField] = '1') OR ([aField] LIKE '1,%') OR ([aField] LIKE '%,1') OR ([aField] LIKE '%,1,%')", $result);
+    }
+
     /**
      * @test
      */