Permalink
Browse files

Refactor schema parsing, include primary key on PostgreSQL and MySQL

This commit refactors the schema parsing.  It eliminates the shared
INFORMATION_SCHEMA based parsing that worked OK on PostgreSQL and
very slowly on MySQL.  The Database#schema public method has been
kept, but the other shared private methods were removed, with the
exception of schema_column_type for mapping database types to ruby
types.  MySQL, PostgreSQL, and SQLite schema parsing all include
the :primary_key entry that shows whether the column is (part of)
the primary key.

PostgreSQL now uses the pg_* system catalogs directly, instead of
the information_schema.  MySQL uses the DESCRIBE syntax to get a
table description.  SQLite was cleaned up slightly, but still uses
the table_info pragma.

The shared Database#schema method now falls back to getting the
schema separately for each table if it can't get the schema for
all tables at once, assuming it knows how to get the schema for
a single table and it knows how to get a list of tables.

PostgreSQL now supports specifying a qualified table name (including
schema) in the call to Database#schema.  Before, the schema had to
be specified explicity using the :schema option, which means it
didn't work correctly with models.  It still defaults to the public
schema if no schema is specified (either explicitly or implicitly).
This means that DB.schema(:s__t) now gives column information for
table t in schema s.

The :numeric_precision and :max_chars entries are no longer included
in the hashes returned by schema.  You should be able to get the same
or similar information using the :db_type entry, which now includes
specified lengths (e.g. varchar(255)).

Since primary keys can now be parsed from the schema, use the schema
information to set primary keys for schema models.

In addition, this commit makes schema changing methods such as
drop_table and alter_table remove the cached schema entry.  It also
has a small fix to drop_view to allow dropping multiple views at
once, so it works just like drop_table.  Additionally, it quotes
the view names.

The schema hash keys are now always supposed to be symbols.

This commit also changes some specs to remove the use of set_schema,
and it adds integration tests to test schema parsing of primary keys,
NULL/NOT NULL, and defaults.

This commit makes MySQL Database#tables work on JDBC as well as using
the native adapter, by using the SHOW TABLES syntax.
  • Loading branch information...
1 parent 34f8955 commit fc8493c86fe3e02decfbc93d055d1065645c1596 @jeremyevans committed Sep 8, 2008
View
@@ -1,5 +1,21 @@
=== HEAD
+* Database#tables now works for MySQL databases using the JDBC adapter (jeremyevans)
+
+* Database#drop_view can now take multiple arguments to drop multiple views at once (jeremyevans)
+
+* Schema modification methods (e.g. drop_table, create_table!) now remove the cached schema entry (jeremyevans)
+
+* Models can now determine their primary keys by looking at the schema (jeremyevans)
+
+* No longer include :numeric_precision and :max_chars entries in the schema column hashes, use the :db_type entry instead (jeremyevans)
+
+* Make schema parsing on PostgreSQL handle implicit schemas (e.g. schema(:schema__table)), so it works with models for tables outside the public schema (jeremyevans)
+
+* Significantly speed up schema parsing on MySQL (jeremyevans)
+
+* Include primary key information when parsing the schema (jeremyevans)
+
* Fix schema generation of composite foreign keys on MySQL (clivecrous, jeremyevans)
=== 2.5.0 (2008-09-03)
@@ -146,11 +146,6 @@ def server_version(server=nil)
@server_version ||= (synchronize(server){|conn| conn.server_version if conn.respond_to?(:server_version)} || super)
end
- # Return an array of symbols specifying table names in the current database.
- def tables(server=nil)
- synchronize(server){|conn| conn.list_tables.map {|t| t.to_sym}}
- end
-
# Support single level transactions on MySQL.
def transaction(server=nil)
synchronize(server) do |conn|
@@ -62,6 +62,11 @@ def server_version
@server_version ||= (m[1].to_i * 10000) + (m[2].to_i * 100) + m[3].to_i
end
+ # Return an array of symbols specifying table names in the current database.
+ def tables(server=nil)
+ self['SHOW TABLES'].server(server).map{|r| r.values.first.to_sym}
+ end
+
# Changes the database in use by issuing a USE statement. I would be
# very careful if I used this.
def use(db_name)
@@ -73,27 +78,18 @@ def use(db_name)
private
- # Always quote identifiers for the schema parser dataset.
- def schema_ds_dataset
- ds = schema_utility_dataset.clone
- ds.quote_identifiers = true
- ds
- end
-
- # Allow other database schema's to be queried using the :database
- # option. Allow all database's schema to be used by setting
- # the :database option to nil. If the database option is not specified,
- # uses the currently connected database.
- def schema_ds_filter(table_name, opts)
- filt = super
- # Restrict it to the given or current database, unless specifically requesting :database = nil
- filt = SQL::BooleanExpression.new(:AND, filt, {:c__table_schema=>opts[:database] || database_name}) if opts[:database] || !opts.include?(:database)
- filt
- end
-
- # MySQL doesn't support table catalogs, so just join on schema and table name.
- def schema_ds_join(table_name, opts)
- [:information_schema__columns, {:table_schema => :table_schema, :table_name => :table_name}, :c]
+ # Use the MySQL specific DESCRIBE syntax to get a table description.
+ def schema_parse_table(table_name, opts)
+ self["DESCRIBE ?", table_name].map do |row|
+ row.delete(:Extra)
+ row[:allow_null] = row.delete(:Null) == 'YES'
+ row[:default] = row.delete(:Default)
+ row[:primary_key] = row.delete(:Key) == 'PRI'
+ row[:default] = nil if row[:default].blank?
+ row[:db_type] = row.delete(:Type)
+ row[:type] = schema_column_type(row[:db_type])
+ [row.delete(:Field).to_sym, row]
+ end
end
end
@@ -150,6 +150,22 @@ def primary_key(table, server=nil)
synchronize(server){|conn| primary_key_for_table(conn, table)}
end
+ # Support :schema__table format for table
+ def schema(table_name=nil, opts={})
+ case table_name
+ when Symbol
+ t, c, a = dataset.send(:split_symbol, table_name)
+ opts[:schema] ||= t
+ table_name = c
+ when SQL::QualifiedIdentifier
+ opts[:schema] ||= table_name.table
+ table_name = table_name.column
+ when SQL::Identifier
+ table_name = table_name.value
+ end
+ super(table_name, opts)
+ end
+
# PostgreSQL uses SERIAL psuedo-type instead of AUTOINCREMENT for
# managing incrementing primary keys.
def serial_primary_key_options
@@ -267,14 +283,55 @@ def primary_key_sequence_for_table(conn, table)
@primary_key_sequences.include?(table) ? @primary_key_sequences[table] : (@primary_key_sequences[table] = conn.sequence(table))
end
- # When the :schema option is used, use the the given schema.
- # When the :schema option is nil, return results for all schemas.
- # If the :schema option is not used, use the public schema.
- def schema_ds_filter(table_name, opts)
- filt = super
- # Restrict it to the given or public schema, unless specifically requesting :schema = nil
- filt = SQL::BooleanExpression.new(:AND, filt, {:c__table_schema=>opts[:schema] || 'public'}) if opts[:schema] || !opts.include?(:schema)
- filt
+ # Set the default of the row to NULL if it is blank, and set
+ # the ruby type for the column based on the database type.
+ def schema_parse_rows(rows)
+ rows.map do |row|
+ row[:default] = nil if row[:default].blank?
+ row[:type] = schema_column_type(row[:db_type])
+ [row.delete(:name).to_sym, row]
+ end
+ end
+
+ # Parse the schema for a single table.
+ def schema_parse_table(table_name, opts)
+ schema_parse_rows(schema_parser_dataset(table_name, opts))
+ end
+
+ # Parse the schema for multiple tables.
+ def schema_parse_tables(opts)
+ schemas = {}
+ schema_parser_dataset(nil, opts).each do |row|
+ (schemas[row.delete(:table).to_sym] ||= []) << row
+ end
+ schemas.each do |table, rows|
+ schemas[table] = schema_parse_rows(rows)
+ end
+ schemas
+ end
+
+ # The dataset used for parsing table schemas, using the pg_* system catalogs.
+ def schema_parser_dataset(table_name, opts)
+ ds = dataset.select(:pg_attribute__attname___name,
+ SQL::Function.new(:format_type, :pg_type__oid, :pg_attribute__atttypmod).as(:db_type),
+ SQL::Function.new(:pg_get_expr, :pg_attrdef__adbin, :pg_class__oid).as(:default),
+ SQL::BooleanExpression.new(:NOT, :pg_attribute__attnotnull).as(:allow_null),
+ SQL::Function.new(:COALESCE, {:pg_attribute__attnum => SQL::Function.new(:ANY, :pg_index__indkey)}.sql_expr, false).as(:primary_key)).
+ from(:pg_class).
+ join(:pg_attribute, :attrelid=>:oid).
+ join(:pg_type, :oid=>:atttypid).
+ left_outer_join(:pg_attrdef, :adrelid=>:pg_class__oid, :adnum=>:pg_attribute__attnum).
+ left_outer_join(:pg_index, :indrelid=>:pg_class__oid, :indisprimary=>true).
+ filter(:pg_attribute__attisdropped=>false).
+ filter(:pg_attribute__attnum > 0).
+ order(:pg_attribute__attnum)
+ if table_name
+ ds.filter!(:pg_class__relname=>table_name.to_s)
+ else
+ ds.select_more!(:pg_class__relname___table)
+ end
+ ds.join!(:pg_namespace, :oid=>:pg_class__relnamespace, :nspname=>opts[:schema] || 'public') if opts[:schema] || !opts.include?(:schema)
+ ds
end
end
@@ -2,7 +2,6 @@ module Sequel
module SQLite
module DatabaseMethods
AUTO_VACUUM = {'0' => :none, '1' => :full, '2' => :incremental}.freeze
- SCHEMA_TYPE_RE = /\A(\w+)\((\d+)\)\z/
SYNCHRONOUS = {'0' => :off, '1' => :normal, '2' => :full}.freeze
TABLES_FILTER = "type = 'table' AND NOT name = 'sqlite_sequence'"
TEMP_STORE = {'0' => :default, '1' => :file, '2' => :memory}.freeze
@@ -86,31 +85,16 @@ def temp_store=(value)
# SQLite supports schema parsing using the table_info PRAGMA, so
# parse the output of that into the format Sequel expects.
def schema_parse_table(table_name, opts)
- rows = self["PRAGMA table_info(?)", table_name].collect do |row|
+ self["PRAGMA table_info(?)", table_name].map do |row|
row.delete(:cid)
- row[:column] = row.delete(:name)
- row[:allow_null] = row.delete(:notnull).to_i == 0 ? 'YES' : 'NO'
+ row[:allow_null] = row.delete(:notnull).to_i == 0
row[:default] = row.delete(:dflt_value)
- row[:primary_key] = row.delete(:pk).to_i == 1 ? true : false
+ row[:primary_key] = row.delete(:pk).to_i == 1
+ row[:default] = nil if row[:default].blank?
row[:db_type] = row.delete(:type)
- if m = SCHEMA_TYPE_RE.match(row[:db_type])
- row[:db_type] = m[1]
- row[:max_chars] = m[2].to_i
- else
- row[:max_chars] = nil
- end
- row[:numeric_precision] = nil
- row
+ row[:type] = schema_column_type(row[:db_type])
+ [row.delete(:name).to_sym, row]
end
- schema_parse_rows(rows)
- end
-
- # SQLite doesn't support getting the schema of all tables at once,
- # so loop through the output of #tables to get them.
- def schema_parse_tables(opts)
- schemas = {}
- tables.each{|table| schemas[table] = schema_parse_table(table, opts)}
- schemas
end
end
@@ -40,6 +40,7 @@ def add_index(table, *args)
#
# See Schema::AlterTableGenerator.
def alter_table(name, generator=nil, &block)
+ @schemas.delete(name.to_sym) if @schemas
generator ||= Schema::AlterTableGenerator.new(self, &block)
alter_table_sql_list(name, generator.operations).flatten.each {|sql| execute_ddl(sql)}
end
@@ -70,8 +71,9 @@ def create_table!(name, generator=nil, &block)
# DB.create_or_replace_view(:cheap_items, "SELECT * FROM items WHERE price < 100")
# DB.create_or_replace_view(:ruby_items, DB[:items].filter(:category => 'ruby'))
def create_or_replace_view(name, source)
+ @schemas.delete(name.to_sym) if @schemas
source = source.sql if source.is_a?(Dataset)
- execute_ddl("CREATE OR REPLACE VIEW #{name} AS #{source}")
+ execute_ddl("CREATE OR REPLACE VIEW #{quote_identifier(name)} AS #{source}")
end
# Creates a view based on a dataset or an SQL string:
@@ -80,7 +82,7 @@ def create_or_replace_view(name, source)
# DB.create_view(:ruby_items, DB[:items].filter(:category => 'ruby'))
def create_view(name, source)
source = source.sql if source.is_a?(Dataset)
- execute_ddl("CREATE VIEW #{name} AS #{source}")
+ execute_ddl("CREATE VIEW #{quote_identifier(name)} AS #{source}")
end
# Removes a column from the specified table:
@@ -106,14 +108,20 @@ def drop_index(table, columns)
#
# DB.drop_table(:posts, :comments)
def drop_table(*names)
- names.each {|n| execute_ddl(drop_table_sql(n))}
+ names.each do |n|
+ @schemas.delete(n.to_sym) if @schemas
+ execute_ddl(drop_table_sql(n))
+ end
end
# Drops a view:
#
# DB.drop_view(:cheap_items)
- def drop_view(name)
- execute_ddl("DROP VIEW #{name}")
+ def drop_view(*names)
+ names.each do |n|
+ @schemas.delete(n.to_sym) if @schemas
+ execute_ddl("DROP VIEW #{quote_identifier(n)}")
+ end
end
# Renames a table:
Oops, something went wrong.

0 comments on commit fc8493c

Please sign in to comment.