Tutorial

How To Use the MySQL BLOB Data Type to Store Images with PHP on Ubuntu 18.04

Published on May 5, 2020
English
How To Use the MySQL BLOB Data Type to Store Images with PHP on Ubuntu 18.04

The author selected Girls Who Code to receive a donation as part of the Write for DOnations program.

Introduction

A Binary Large Object (BLOB) is a MySQL data type that can store binary data such as images, multimedia, and PDF files.

When creating applications that require a tightly-coupled database where images should be in sync with related data (for example, an employee portal, a student database, or a financial application), you might find it convenient to store images such as students’ passport photos and signatures in a MySQL database alongside other related information.

This is where the MySQL BLOB data type comes in. This programming approach eliminates the need for creating a separate file system for storing images. The scheme also centralizes the database, making it more portable and secure because the data is isolated from the file system. Creating backups is also more seamless since you can create a single MySQL dump file that contains all your data.

Retrieving data is faster, and when creating records you can be sure that data validation rules and referential integrity are maintained especially when using MySQL transactions.

In this tutorial, you will use the MySQL BLOB data type to store images with PHP on Ubuntu 18.04.

Prerequisites

To follow along with this guide, you will need the following:

Step 1 — Creating a Database

You’ll start off by creating a sample database for your project. To do this, SSH in to your server and then run the following command to log in to your MySQL server as root:

  1. sudo mysql -u root -p

Enter the root password of your MySQL database and hit ENTER to continue.

Then, run the following command to create a database. In this tutorial we’ll name it test_company:

  1. CREATE DATABASE test_company;

Once the database is created, you will see the following output:

Output
Query OK, 1 row affected (0.01 sec)

Next, create a test_user account on the MySQL server and remember to replace PASSWORD with a strong password:

  1. CREATE USER 'test_user'@'localhost' IDENTIFIED BY 'PASSWORD';

You’ll see the following output:

Output
Query OK, 0 rows affected (0.01 sec)

To grant test_user full privileges on the test_company database, run:

  1. GRANT ALL PRIVILEGES ON test_company.* TO 'test_user'@'localhost';

Make sure you get the following output:

Output
Query OK, 0 rows affected (0.01 sec)

Finally, flush the privileges table in order for MySQL to reload the permissions:

  1. FLUSH PRIVILEGES;

Ensure you see the following output:

Output
Query OK, 0 rows affected (0.01 sec)

Now that the test_company database and test_user are ready, you’ll move on to creating a products table for storing sample products. You’ll use this table later to insert and retrieve records to demonstrate how MySQL BLOB works.

Log out from the MySQL server:

  1. QUIT;

Then, log back in again with the credentials of the test_user that you created:

  1. mysql -u test_user -p

When prompted, enter the password for the test_user and hit ENTER to continue. Next, switch to the test_company database by typing the following:

  1. USE test_company;

Once the test_company database is selected, MySQL will display:

Output
Database changed

Next, create a products table by running:

  1. CREATE TABLE `products` (product_id BIGINT PRIMARY KEY AUTO_INCREMENT, product_name VARCHAR(50), price DOUBLE, product_image BLOB) ENGINE = InnoDB;

This command creates a table named products. The table has four columns:

  • product_id: This column uses a BIGINT data type in order to accommodate a large list of products up to a maximum of 2⁶³-1 items. You’ve marked the column as PRIMARY KEY to uniquely identify products. In order for MySQL to handle the generation of new identifiers for inserted columns, you have used the keyword AUTO_INCREMENT.

  • product_name: This column holds the names of the products. You’ve used the VARCHAR data type since this field will generally handle alphanumerics up to a maximum of 50 characters—the limit of 50 is just a hypothetical value used for the purpose of this tutorial.

  • price: For demonstration purposes, your products table contains the price column to store the retail price of products. Since some products may have floating values (for example, 23.69, 45.36, 102.99), you’ve used the DOUBLE data type.

  • product_image: This column uses a BLOB data type to store the actual binary data of the products’ images.

You’ve used the InnoDB storage ENGINE for the table to support a wide range of features including MySQL transactions. After executing this for creating the products table, you’ll see the following output:

Output
Query OK, 0 rows affected (0.03 sec)

Log out from your MySQL server:

  1. QUIT;

You will get the following output

Output
Bye

The products table is now ready to store some records including products’ images and you’ll populate it with some products in the next step.

Step 2 — Creating PHP Scripts for Connecting and Populating the Database

In this step, you’ll create a PHP script that will connect to the MySQL database that you created in Step 1. The script will prepare three sample products and insert them into the products table.

To create the PHP code, open a new file with your text editor:

  1. sudo nano /var/www/html/config.php

Then, enter the following information into the file and replace PASSWORD with the test_user password that you created in Step 1:

/var/www/html/config.php
<?php

define('DB_NAME', 'test_company');
define('DB_USER', 'test_user');
define('DB_PASSWORD', 'PASSWORD');
define('DB_HOST', 'localhost');

$pdo = new PDO("mysql:host=" . DB_HOST . "; dbname=" . DB_NAME, DB_USER, DB_PASSWORD);
$pdo->setAttribute(PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION);
$pdo->setAttribute(PDO::ATTR_EMULATE_PREPARES, false);

Save and close the file.

In this file, you’ve used four PHP constants to connect to the MySQL database that you created in Step 1:

  • DB_NAME : This constant holds the name of the test_company database.

  • DB_USER : This variable holds the test_user username.

  • DB_PASSWORD : This constant stores the MySQL PASSWORD of the test_user account.

  • DB_HOST: This represents the server where the database resides. In this case, you are using the localhost server.

The following line in your file initiates a PHP Data Object (PDO) and connects to the MySQL database:

...
$pdo = new PDO("mysql:host=" . DB_HOST . "; dbname=" . DB_NAME, DB_USER, DB_PASSWORD);
...

Toward the end of the file, you’ve set a couple of PDO attributes:

  • ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION: This attribute instructs PDO to throw an exception that can be logged for debugging purposes.
  • ATTR_EMULATE_PREPARES, false: This option increases security by telling the MySQL database engine to do the prepare instead of PDO.

You’ll include the /var/www/html/config.php file in two PHP scripts that you will create next for inserting and retrieving records respectively.

First, create the /var/www/html/insert_products.php PHP script for inserting records to the products table:

  1. sudo nano /var/www/html/insert_products.php

Then, add the following information into the /var/www/html/insert_products.php file:

/var/www/html/insert_products.php
<?php

require_once 'config.php';

$products = [];

$products[] = [
              'product_name' => 'VIRTUAL SERVERS',
              'price' => 5,
              'product_image' => file_get_contents("https://i.imgur.com/VEIKbp0.png")
              ];

$products[] = [
              'product_name' => 'MANAGED KUBERNETES',
              'price' => 30,
              'product_image' => file_get_contents("https://i.imgur.com/cCc9Gw9.png")
              ];

$products[] = [
              'product_name' => 'MySQL DATABASES',
              'price' => 15,
              'product_image' => file_get_contents("https://i.imgur.com/UYcHkKD.png" )
              ];

$sql = "INSERT INTO products(product_name, price, product_image) VALUES (:product_name, :price, :product_image)";

foreach ($products as $product) {
    $stmt = $pdo->prepare($sql);
    $stmt->execute($product);
}

echo "Records inserted successfully";

Save and close the file.

In the file, you’ve included the config.php file at the top. This is the first file you created for defining the database variables and connecting to the database. The file also initiates a PDO object and stores it in a $pdo variable.

Next, you’ve created an array of the products’ data to be inserted into the database. Apart from the product_name and price, which are prepared as strings and numeric values respectively, the script uses PHP’s in-built file_get_contents function to read images from an external source and pass them as strings to the product_image column.

Next, you have prepared an SQL statement and used the PHP foreach{...} statement to insert each product into the database.

To execute the /var/www/html/insert_products.php file, run it in your browser window using the following URL. Remember to replace your-server-IP with the public IP address of your server:

http://your-server-IP/insert_products.php

After executing the file, you’ll see a success message in your browser confirming records were inserted into the database.

A success message showing that records were inserted to database

You have successfully inserted three records containing product images into the products table. In the next step, you’ll create a PHP script for retrieving these records and displaying them in your browser.

Step 3 — Displaying Products’ Information From the MySQL Database

With the products’ information and images in the database, you’re now going to code another PHP script that queries and displays the products’ information in an HTML table on your browser.

To create the file, type the following:

  1. sudo nano /var/www/html/display_products.php

Then, enter the following information into the file:

/var/www/html/display_products.php
<html>
  <title>Using BLOB and MySQL</title>
  <body>

  <?php

  require_once 'config.php';

  $sql = "SELECT * FROM products";
  $stmt = $pdo->prepare($sql);
  $stmt->execute();
  ?>

  <table border = '1' align = 'center'> <caption>Products Database</caption>
    <tr>
      <th>Product Id</th>
      <th>Product Name</th>
      <th>Price</th>
      <th>Product Image</th>
    </tr>

  <?php
  while ($row = $stmt->fetch(PDO::FETCH_ASSOC)) {
      echo '<tr>';
      echo '<td>' . $row['product_id'] . '</td>';
      echo '<td>' . $row['product_name'] . '</td>';
      echo '<td>' . $row['price'] . '</td>';
      echo '<td>' .
      '<img src = "data:image/png;base64,' . base64_encode($row['product_image']) . '" width = "50px" height = "50px"/>'
      . '</td>';
      echo '</tr>';
  }
  ?>

  </table>
  </body>
</html>

Save the changes to the file and close it.

Here you’ve again included the config.php file in order to connect to the database. Then, you have prepared and executed an SQL statement using PDO to retrieve all items from the products table using the SELECT * FROM products command.

Next, you have created an HTML table and populated it with the products’ data using the PHP while() {...} statement. The line $row = $stmt->fetch(PDO::FETCH_ASSOC) queries the database and stores the result in the $row variable as a multi-dimensional array, which you have then displayed in an HTML table column using the $row['column_name'] syntax.

The images from the product_image column are enclosed inside the <img src = ""> tags. You’ve used the width and height attributes to resize the images to a smaller size that can fit in the HTML table column.

In order to convert the data held by the BLOB data type back to images, you’ve used the in-built PHP base64_encode function and the following syntax for the Data URI scheme:

data:media_type;base64, base_64_encoded_data

In this case, the image/png is the media_type and the Base64 encoded string from the product_image column is the base_64_encoded_data.

Next, execute the display_products.php file in a web browser by typing the following address:

http://your-server-IP/display_products.php

After running the display_products.php file in your browser, you will see an HTML table with a list of products and associated images.

List of products from MySQL database

This confirms that the PHP script for retrieving images from MySQL is working as expected.

Conclusion

In this guide, you used the MySQL BLOB data type to store and display images with PHP on Ubuntu 18.04. You’ve also seen the basic advantages of storing images in a database as opposed to storing them in a file system. These include portability, security, and ease of backup. If you are building an application such as a students’ portal or employees’ database that requires information and related images to be stored together, then this technology can be of great use to you.

For more information about the supported data types in MySQL follow the MySQL Data Types guide. If you’re interested in further content relating to MySQL and PHP, check out the following tutorials:

Thanks for learning with the DigitalOcean Community. Check out our offerings for compute, storage, networking, and managed databases.

Learn more about us


About the authors


Still looking for an answer?

Ask a questionSearch for more help

Was this helpful?
 
1 Comments


This textbox defaults to using Markdown to format your answer.

You can type !ref in this text area to quickly search our full set of tutorials, documentation & marketplace offerings and insert the link!

Is there a limit to the size of the image? I notice the example pics are 50x50px PNGs, which should fit in the 65kb max for a column.

Try DigitalOcean for free

Click below to sign up and get $200 of credit to try our products over 60 days!

Sign up

Join the Tech Talk
Success! Thank you! Please check your email for further details.

Please complete your information!

Get our biweekly newsletter

Sign up for Infrastructure as a Newsletter.

Hollie's Hub for Good

Working on improving health and education, reducing inequality, and spurring economic growth? We'd like to help.

Become a contributor

Get paid to write technical tutorials and select a tech-focused charity to receive a matching donation.

Welcome to the developer cloud

DigitalOcean makes it simple to launch in the cloud and scale up as you grow — whether you're running one virtual machine or ten thousand.

Learn more
DigitalOcean Cloud Control Panel