Sequel: The Database Toolkit for Ruby

Sequel is a database access toolkit for Ruby. Sequel provides thread safety, connection pooling, and a concise DSL for constructing queries and table schemas.

Sequel makes it easy to deal with multiple records without having to break your teeth on SQL.

Resources

To check out the source code:

git clone git://github.com/jeremyevans/sequel.git

Contact

If you have any comments or suggestions please post to the Google group.

Installation

sudo gem install sequel

Supported Databases

Sequel currently supports:

  • ADO (on Windows)

  • DBI

  • Informix

  • MySQL

  • ODBC

  • Oracle

  • PostgreSQL

  • SQLite 3

There are also experimental adapters for DB2, OpenBase and JDBC (on JRuby).

A Short Example

require 'rubygems'
require 'sequel'

DB = Sequel.sqlite # memory database

DB.create_table :items do # Create a new table
  column :name, :text
  column :price, :float
end

items = DB[:items] # Create a dataset

# Populate the table
items << {:name => 'abc', :price => rand * 100}
items << {:name => 'def', :price => rand * 100}
items << {:name => 'ghi', :price => rand * 100}

# Print out the number of records
puts "Item count: #{items.count}"

# Print out the records in descending order by price
items.reverse_order(:price).print

# Print out the average price
puts "The average price is: #{items.avg(:price)}"

The Sequel Console

Sequel includes an IRB console for quick’n’dirty access to databases. You can use it like this:

sequel sqlite://test.db # test.db in current directory

You get an IRB session with the database object stored in DB.

An Introduction

Sequel is designed to take the hassle away from connecting to databases and manipulating them. Sequel deals with all the boring stuff like maintaining connections, formatting SQL correctly and fetching records so you can concentrate on your application.

Sequel uses the concept of datasets to retrieve data. A Dataset object encapsulates an SQL query and supports chainability, letting you fetch data using a convenient Ruby DSL that is both concise and infinitely flexible.

For example, the following one-liner returns the average GDP for the five biggest countries in the middle east region:

DB[:countries].filter(:region => 'Middle East').reverse_order(:area).limit(5).avg(:GDP)

Which is equivalent to:

SELECT avg(GDP) FROM countries WHERE region = 'Middle East' ORDER BY area DESC LIMIT 5

Since datasets retrieve records only when needed, they can be stored and later reused. Records are fetched as hashes (they can also be fetched as custom model objects), and are accessed using an Enumerable interface:

middle_east = DB[:countries].filter(:region => 'Middle East')
middle_east.order(:name).each {|r| puts r[:name]}

Sequel also offers convenience methods for extracting data from Datasets, such as an extended map method:

middle_east.map(:name) #=> ['Egypt', 'Greece', 'Israel', ...]

Or getting results as a transposed hash, with one column as key and another as value:

middle_east.to_hash(:name, :area) #=> {'Israel' => 20000, 'Greece' => 120000, ...}

Getting Started

Connecting to a database

To connect to a database you simply provide Sequel with a URL:

require 'sequel'
DB = Sequel.connect('sqlite://blog.db')

The connection URL can also include such stuff as the user name and password:

DB = Sequel.connect('postgres://cico:12345@localhost:5432/mydb')

You can also specify optional parameters, such as the connection pool size, or loggers for logging SQL queries:

DB = Sequel.connect("postgres://postgres:postgres@localhost/my_db",
  :max_connections => 10, :loggers => [Logger.new('log/db.log']))

You can specify a block to connect, which will disconnect from the database after it completes:

Sequel.connect('postgres://cico:12345@localhost:5432/mydb'){|db| db[:posts].delete}

Arbitrary SQL queries

DB.execute("create table t (a text, b text)")
DB.execute("insert into t values ('a', 'b')")

Or more succinctly:

DB << "create table t (a text, b text)"
DB << "insert into t values ('a', 'b')"

You can also create datasets based on raw SQL:

dataset = DB['select * from items']
dataset.count # will return the number of records in the result set
dataset.map(:id) # will return an array containing all values of the id column in the result set

You can also fetch records with raw SQL through the dataset:

DB['select * from items'].each do |row|
  p row
end

Getting Dataset Instances

Dataset is the primary means through which records are retrieved and manipulated. You can create an blank dataset by using the dataset method:

dataset = DB.dataset

Or by using the from methods:

posts = DB.from(:posts)

The recommended way is the equivalent shorthand:

posts = DB[:posts]

Datasets will only fetch records when you explicitly ask for them. Datasets can be manipulated to filter through records, change record order, join tables, etc..

Retrieving Records

You can retrieve records by using the all method:

posts.all

The all method returns an array of hashes, where each hash corresponds to a record.

You can also iterate through records one at a time:

posts.each{|row| p row}

Or perform more advanced stuff:

posts.map(:id)
posts.inject({}){|h, r| h[r[:id]] = r[:name]}

You can also retrieve the first record in a dataset:

posts.first

Or retrieve a single record with a specific value:

posts[:id => 1]

If the dataset is ordered, you can also ask for the last record:

posts.order(:stamp).last

Filtering Records

The simplest way to filter records is to provide a hash of values to match:

my_posts = posts.filter(:category => 'ruby', :author => 'david')

You can also specify ranges:

my_posts = posts.filter(:stamp => (Date.today - 14)..(Date.today - 7))

Or lists of values:

my_posts = posts.filter(:category => ['ruby', 'postgres', 'linux'])

Sequel also accepts expressions:

my_posts = posts.filter(:stamp > Date.today << 1)

Some adapters (like postgresql) will also let you specify Regexps:

my_posts = posts.filter(:category => /ruby/i)

You can also use an inverse filter:

my_posts = posts.exclude(:category => /ruby/i)
my_posts = posts.filter(:category => /ruby/i).invert # same as above

You can also specify a custom WHERE clause using a string:

posts.filter('stamp IS NOT NULL')

You can use parameters in your string, as well (ActiveRecord style):

posts.filter('(stamp < ?) AND (author != ?)', Date.today - 3, author_name)
posts.filter((:stamp < Date.today - 3) & ~(:author => author_name)) # same as above

Datasets can also be used as subqueries:

DB[:items].filter('price > ?', DB[:items].select('AVG(price) + 100'))

After filtering you can retrieve the matching records by using any of the retrieval methods:

my_posts.each{|row| p row}

See the doc/dataset_filtering.rdoc file for more details.

Summarizing Records

Counting records is easy:

posts.filter(:category => /ruby/i).count

And you can also query maximum/minimum values:

max_value = DB[:history].max(:value)

Or calculate a sum:

total = DB[:items].sum(:price)

Ordering Records

Ordering datasets is simple:

posts.order(:stamp) # ORDER BY stamp
posts.order(:stamp, :name) # ORDER BY stamp, name

You can also specify descending order

posts.order(:stamp.desc) # ORDER BY stamp DESC

Deleting Records

Deleting records from the table is done with delete:

posts.filter('stamp < ?', Date.today - 3).delete

Inserting Records

Inserting records into the table is done with insert:

posts.insert(:category => 'ruby', :author => 'david')
posts << {:category => 'ruby', :author => 'david'} # same as above

Updating Records

Updating records in the table is done with update:

posts.filter('stamp < ?', Date.today - 7).update(:state => 'archived')

Joining Tables

Joining is very useful in a variety of scenarios, for example many-to-many relationships. With Sequel it’s really easy:

order_items = DB[:items].join(:order_items, :item_id => :id).
  filter(:order_items__order_id => 1234)

This is equivalent to the SQL:

SELECT * FROM items LEFT OUTER JOIN order_items
ON order_items.item_id = items.id 
WHERE order_items.order_id = 1234

You can then do anything you like with the dataset:

order_total = order_items.sum(:price)

Which is equivalent to the SQL:

SELECT sum(price) FROM items LEFT OUTER JOIN order_items
ON order_items.item_id = items.id
WHERE order_items.order_id = 1234

Graphing Datasets

When retrieving records from joined datasets, you get the results in a single hash, which is subject to clobbering:

DB[:items].join(:order_items, :item_id => :id).first
=> {:id=>(could be items.id or order_items.id), :item_id=>order_items.order_id}

Using graph, you can split the result hashes into subhashes, one per join:

DB[:items].graph(:order_items, :item_id => :id).first
=> {:items=>{:id=>items.id}, :order_items=>{:id=>order_items.id, :item_id=>order_items.item_id}}