4 Ways to Fix Error 1048 “Column ‘…’ cannot be null” in MySQL

If you’re getting error 1048 that reads something like “Column ‘ColumnName’ cannot be null” (where ColumnName is the name of a column you’re trying to insert data into), then it’s probably because you’re trying to insert a NULL value into that column, but the column has a NOT NULL constraint (which prevents NULL values from being inserted).

We have a few options when it comes to fixing this issue. The most obvious is to ensure we provide a non-NULL value for the column. Alternatively, if the column should be able to accept NULL values, then we can remove the NOT NULL constraint from the column. Another option is to use the IGNORE keyword to ignore the error. And another way to deal with the error is to disable strict mode.

Example of Error

Here’s an example of code that produces the error:

INSERT INTO Products ( ProductName, ProductDescription )
VALUES ( 'Hammer', NULL );

Result:

ERROR 1048 (23000): Column 'ProductDescription' cannot be null

We get an error because we tried to insert NULL into the ProductDescription column, but that column doesn’t allow NULL values. We know this because the error message tells us that the ProductDescription column cannot be NULL.

We can use the SHOW CREATE TABLE statement to check the table’s definition:

SHOW CREATE TABLE Products;

Result:

+----------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Table    | Create Table                                                                                                                                                                      |
+----------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Products | CREATE TABLE `Products` (
  `ProductName` varchar(255) NOT NULL,
  `ProductDescription` varchar(1000) NOT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci |
+----------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+

We can see that this table contains two columns, both of which have NOT NULL constraints.

Solution 1 – Provide a non-NULL Value

The most obvious solution is to provide a non-NULL value for the column.

Example:

INSERT INTO Products ( ProductName, ProductDescription )
VALUES ( 'Hammer', 'Left handed edition' );

Result:

Query OK, 1 row affected (0.00 sec)

Providing a non-NULL value resolved our issue.

Solution 2 – Remove the NOT NULL Constraint

If we determine that the column really shouldn’t have a NOT NULL constraint, we can remove it before inserting data.

Example:

ALTER TABLE Products 
MODIFY ProductDescription varchar(1000) NULL;

Result:

Query OK, 0 rows affected (0.03 sec)
Records: 0  Duplicates: 0  Warnings: 0

This message indicates that we successfully removed the NOT NULL constraint. Or perhaps more accurately, it indicates that we modified the column to allow NULL values.

We could also have omitted the NULL keyword, and the column would have been redefined without the NOT NULL constraint, like this:

ALTER TABLE Products 
MODIFY ProductDescription varchar(1000);

Now let’s try inserting NULL into that column again:

INSERT INTO Products ( ProductName, ProductDescription )
VALUES ( 'Monkey Wrench', NULL );

Result:

Query OK, 1 row affected (0.00 sec)

This time it was successful.

Let’s take a look at the data in our table:

SELECT * FROM Products;

Result:

+---------------+---------------------+
| ProductName   | ProductDescription  |
+---------------+---------------------+
| Hammer        | Left handed edition |
| Monkey Wrench | NULL                |
+---------------+---------------------+

We can see that both rows from our examples have been inserted successfully.

Solution 3 – Use the IGNORE Clause

Another way to deal with the issue is to use the IGNORE clause in our INSERT statement.

Let’s drop the table and start again:

DROP TABLE Products;
CREATE TABLE Products (
  ProductName varchar(255) NOT NULL,
  ProductDescription varchar(1000) NOT NULL
);

Now let’s try to insert some values that contain NULL:

INSERT INTO Products ( ProductName, ProductDescription )
VALUES 
    ( 'Hammer', 'Left handed edition' ),
    ( 'Saw', NULL ),
    ( 'Wrench', NULL ),
    ( 'Screw Driver', 'Right handed edition' );

Result:

ERROR 1048 (23000): Column 'ProductDescription' cannot be null

As expected, we get the error.

Now let’s try again, but with the IGNORE keyword:

INSERT IGNORE INTO Products ( ProductName, ProductDescription )
VALUES 
    ( 'Hammer', 'Left handed edition' ),
    ( 'Saw', NULL ),
    ( 'Wrench', NULL ),
    ( 'Screw Driver', 'Right handed edition' );

Result:

Query OK, 4 rows affected, 1 warning (0.00 sec)
Records: 4  Duplicates: 0  Warnings: 1

This time the data was inserted successfully.

However, we did get a warning. Let’s check it:

SHOW WARNINGS;

Result:

+---------+------+--------------------------------------------+
| Level   | Code | Message                                    |
+---------+------+--------------------------------------------+
| Warning | 1048 | Column 'ProductDescription' cannot be null |
+---------+------+--------------------------------------------+

So the IGNORE keyword downgraded the error to a warning.

Let’s check the contents of the table:

SELECT 
    *, 
    ISNULL(ProductDescription)
FROM Products;

Result:

+--------------+----------------------+----------------------------+
| ProductName  | ProductDescription   | ISNULL(ProductDescription) |
+--------------+----------------------+----------------------------+
| Hammer       | Left handed edition  |                          0 |
| Saw          |                      |                          0 |
| Wrench       |                      |                          0 |
| Screw Driver | Right handed edition |                          0 |
+--------------+----------------------+----------------------------+

I added the third column to show that MySQL doesn’t actually insert NULL into the column when we use the IGNORE keyword. Instead, it inserts the implicit default value for the data type. In our case, the data type is a string, and so it inserted the empty string.

Solution 4 – Disable Strict SQL Mode

The whole reason we get an error is because we have strict SQL mode enabled. When we used the IGNORE keyword, we were basically just overcoming the error we’d get due to the fact that we have strict mode enabled.

So another way to deal with the error is to disable strict mode altogether.

Here’s what my SQL mode looks like:

SELECT @@SESSION.sql_mode;

Result:

ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO,NO_ENGINE_SUBSTITUTION

Strict SQL mode is in effect if either STRICT_ALL_TABLES or STRICT_TRANS_TABLES is enabled. My SQL mode contains STRICT_TRANS_TABLES, which means I have strict SQL mode enabled. It also contains related modes NO_ZERO_IN_DATE, NO_ZERO_DATE, and ERROR_FOR_DIVISION_BY_ZERO. Depending on your MySQL implementation, you may or may not have these other modes.

Let’s disable strict mode:

SET @@sql_mode = sys.list_drop(@@sql_mode, 'STRICT_TRANS_TABLES,NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO');
SELECT @@SESSION.sql_mode;

Result:

ONLY_FULL_GROUP_BY,NO_ENGINE_SUBSTITUTION

We can see that our SQL mode no longer contains STRICT_TRANS_TABLES. I also removed NO_ZERO_IN_DATE, NO_ZERO_DATE, and ERROR_FOR_DIVISION_BY_ZERO.

Let’s drop the table and start again:

DROP TABLE Products;
CREATE TABLE Products (
  ProductName varchar(255) NOT NULL,
  ProductDescription varchar(1000) NOT NULL
);

Now let’s try to insert some values that contain NULL:

INSERT INTO Products ( ProductName, ProductDescription )
VALUES 
    ( 'Hammer', 'Left handed edition' ),
    ( 'Saw', NULL ),
    ( 'Wrench', NULL ),
    ( 'Screw Driver', 'Right handed edition' );

Result:

Query OK, 4 rows affected, 1 warning (0.00 sec)
Records: 4  Duplicates: 0  Warnings: 1

We get the same result that we got when using the IGNORE keyword.

Let’s check the warnings:

SHOW WARNINGS;

Result:

+---------+------+--------------------------------------------+
| Level   | Code | Message                                    |
+---------+------+--------------------------------------------+
| Warning | 1048 | Column 'ProductDescription' cannot be null |
+---------+------+--------------------------------------------+

As expected, the warning tells us that the column can’t be NULL.

And let’s check the data:

SELECT 
    *, 
    ISNULL(ProductDescription)
FROM Products;

Result:

+--------------+----------------------+----------------------------+
| ProductName  | ProductDescription   | ISNULL(ProductDescription) |
+--------------+----------------------+----------------------------+
| Hammer       | Left handed edition  |                          0 |
| Saw          |                      |                          0 |
| Wrench       |                      |                          0 |
| Screw Driver | Right handed edition |                          0 |
+--------------+----------------------+----------------------------+

Again, same result as with the IGNORE keyword.

So, disabling strict SQL mode allowed us to insert NULL values without getting an error. Or more accurately, it allowed us to attempt to insert NULL values without error. As stated, using this method doesn’t actually insert NULL. It inserts the implicit default value for the data type.

When it comes to using IGNORE vs disabling strict SQL mode, there are a few nuances to consider. The MySQL documentation contains a comparison of IGNORE and strict SQL mode that can be helpful when deciding which option to use.