Connecting a MySQL database

You can use a MySQL database as a data source for your GraphQL API by extending the API with the @dbquery directive.

Tip: To quickly generate your GraphQL on a MySQL backend with the stepzen import mysql command, see Tutorial: Create a GraphQL API for a MySQL database.

Any Query or Mutation field in your GraphQL schema can be annotated with the @dbquery directive to connect to a database backend:

@dbquery (type: String!, query: String, dml: enum, table: String, configuration: String!)

For more information on the @dbquery directive, see the Custom directives reference.

Use the arguments in the following sections when you want to connect to a MSSQL database as a data source for your GraphQL API.

type

Required. This argument specifies the type of database to query. Supported values are mysql, postgresql, mssql, and snowflake.

table

Optional. The value of this argument is the name of the database table to be queried. While this value is optional, one of either table or query must be specified.

Using the table argument is the equivalent of writing select * from [table]. The field names of the GraphQL type of the annotated field must match the column names of the underlying database table. Thus, if the table has a NAME column, it will populate the NAME field of the GraphQL type.

If the annotated field has arguments, they are used to construct the WHERE clause of the SQL query. For example, let's look at the following annotated field:

customerById (id: ID!): Customer
  @dbquery (
    type: "mysql"
    table: "customers"
    configuration: "mysql_config"
  )

The directive passes the following database query to the database specified by the configuration argument (in this example, mysql_config):

SELECT `id`, `name`, `email`, `creditCard` FROM `customers` WHERE `id` = ?

where id, name, email and creditCard are the columns of the MYSQL customers table that match the fields of the Customer type.

If the annotated field has multiple arguments, they are combined in the SQL WHERE clause with an AND.

Note: MYSQL comparisons are case-insensitive, so the argument id will match columns named id, Id, id or ID.

If the annotated field has multiple arguments, they are combined in the SQL WHERE clause with an AND.

query

Optional. The value of this argument is the SQL query whose results are used to populate the sub-fields of the annotated field. While this value is optional, one of either table or query must be specified.

The query argument is useful when you need to perform a complex query, or when the table column names and GraphQL type fields do not match. For example:

customerById (id: ID!): Customer
  @dbquery (
    type: "mysql",
    query: "SELECT `id`, `full_name` AS `name`, `email` FROM `customer` WHERE `id` = ? AND `creditCard` is not NULL",
    configuration: "mysql_config"
  )

The directive executes the specified SQL query on the database specified by the mysql_config. The SQL query both renames full_name to name so it matches the field name in the GraphQL type Customer, and retrieves only those customers who have a credit card.

Unquoted column names in MYSQL are preserved, so the column names in the query do not require quotation marks.

configuration

Required. This argument identifies which configuration in the config.yaml file should be used to connect to the database.

A MySQL database configuration contains the dsn for connecting to your database, and will look similar to this:

configurationset:
  - configuration:
      name: mysql_config
      dsn: username:password@tcp(a.b.c.d:port)/dbname

In this example, mysql_config is the named configuration that will be referenced by the configuration property of @dbquery as configuration: mysql_config.

To learn more about the configuration settings for connecting to your MySQL database, see MySQL configuration.

dml

Optional. Use this argument when the annotated field is a mutation. Its value is an enum that specifies the type of mutation being performed. Valid values are INSERT and DELETE (do not enclose the value in quotation marks because it is an enum).

To avoid conflicts, you cannot use this argument when query is specified.

The following is an example of a mutation with a annotated field whose dml argument value is INSERT:

type Mutation {
  addCustomerById(id: ID!, name: String!, email: String!): Customer
    @dbquery(
      type: "mysql"
      table: "customer"
      dml: INSERT
      configuration: "mysql_config"
    )
}

The selection of the addCustomer field of this mutation results in the execution of an insert statement followed by a select statement in the MYSQL backend, adding the customer and using the inserted values to populate the returned GraphQL Customer type:

INSERT INTO `customer`(`id`, `name`, `email`) VALUES (?, ?, ?)
SELECT `id`, `name`, `email` FROM `customer` WHERE `id` = ? AND `name` = ? and `email` = ?

Next, let's look at an example of using DELETE:

type Mutation {
  removeCustomerById(id: ID!): Customer
    @dbquery(
      type: "mysql"
      table: "customer"
      dml: DELETE
      configuration: "mysql_config"
    )
}

The selection of the removeCustomerById field of this mutation results in the execution of a select statement followed by a delete statement in the MYSQL backend, resulting in the removal of the customer with the specified id and using the deleted values to populate the returned GraphQL Customer type:

SELECT `id`, `name`, `email` FROM `customer` WHERE `id` = ?
DELETE FROM `customer` WHERE `id` = ?