=head1 NAME DBIx::Class::Manual::SQLHackers::CREATE - DBIx::Class for SQL Hackers - CREATE =head1 Table of Contents =over =item L =item CREATE =item L =item L =item L =item L =item L =head1 Database structure To use DBIx::Class, we need to teach it about the layout of the underlying database. Several methods are supported. The built-in method involves defining your database structure as a set of perl modules. The other oft used method is to import the definitions from an existing database using the module L. Once a DBIx::Class schema (set of classes describing the database) has been created, built-in methods can be used to export it to SQL using L. =head2 Using Loader Install L and decide on a name for your schema classes. Run the included L script. dbicdump -Ilib -o dump_directory=./lib \ -o components='["InflateColumn::DateTime"]' \ -o preserve_case=1 \ MyApp::Schema dbi:mysql:database=foo user pass '{ quote_char => "`" }' =head2 Manual Result class creation (and understanding Loader results) =head3 CREATE TABLE =head4 Standard basic table creation in SQL: CREATE TABLE users ( id INTEGER AUTO_INCREMENT, username VARCHAR(255), dob DATE, realname VARCHAR(255), password VARCHAR(255) ); We'll get to tables with references (foreign keys) later, here's the translation to DBIx::Class: The recommended version: package MyDatabase::Schema::Result::User; use strict; use warnings; use base 'DBIx::Class::Core'; __PACKAGE__->table('users'); __PACKAGE__->add_columns( id => { data_type => 'integer', is_auto_increment => 1, }, username => { data_type => 'varchar', size => 255, }, dob => { data_type => 'date', }, realname => { data_type => 'varchar', size => 255, }, password => { data_type => 'varchar', size => 255, }, ); __PACKAGE__->set_primary_key('id'); __PACKAGE__->add_unique_constraint('uniq_username' => ['username']); 1; The fully descriptive version is required if you want to have DBIx::Class create your CREATE TABLE sql for you later. Many DBIC components also use settings in the column info hashrefs to decide how to treat the data for those columns. The snappy version: package MyDatabase::Schema::Result::User; use strict; use warnings; use base 'DBIx::Class::Core'; __PACKAGE__->table('users'); __PACKAGE__->add_columns( id => { data_type => 'integer', is_auto_increment => 1, }, qw/username dob realname password/ ); __PACKAGE__->set_primary_key('id'); 1; This shows a minimal Result class to represent our "users" table. DBIx::Class itself does not use or care about the field types or lengths. However many external components exist on CPAN, and some of may use this information. =head4 Table creation with references: A relational database isn't worth much if we don't actually use references and constraints, so here is an example which constrains the B column to only contain B values from the *users* table. CREATE TABLE posts ( id INTEGER AUTO_INCREMENT, user_id INTEGER, created_date DATETIME, title VARCHAR(255), post TEXT, INDEX posts_idx_user_id (user_id), PRIMARY KEY (id), CONSTRAINT posts_fk_user_id FOREIGN KEY (user_id) REFERENCES users (id) ); In DBIx::Class this is achieved by adding L definitions to the class: package MyDatabase::Schema::Result::Post; use strict; use warnings; use base 'DBIx::Class::Core'; __PACKAGE__->table('posts'); __PACKAGE__->add_columns( id => { data_type => 'integer', is_auto_increment => 1, }, user_id => { data_type => 'integer', }, created_date => { data_type => 'datetime', }, title => { data_type => 'varchar', size => 255, }, post => { data_type => 'text', }, ); __PACKAGE__->set_primary_key('id'); __PACKAGE__->belongs_to('user', 'MyDatabase::Schema::Result::User', 'user_id'); 1; The B relation allows us to refer to the B who authored a post as the object representing the user, rather than as just the integer tha database uses as the linking information. To allow access from the B object back to the posts they have written, we need to define another relationship in the User class: __PACKAGE__->has_many('posts', 'MyDatabase::Schema::Result::Post', 'user_id'); =head3 CREATE VIEW In SQL, a simple view that returns all users and their posts: CREATE VIEW userposts AS SELECT posts.user_id, users.username, users.dob, users.realname, posts.createddate, posts.title, posts.post FROM users JOIN posts ON (users.id = posts.user_id) In DBIx::Class this can have a Result Class of its own: package MyDatabase::Schema::Result::UserPosts; use base qw/DBIx::Class::Core/; __PACKAGE__->table_class('DBIx::Class::ResultSource::View'); __PACKAGE__->table('user_posts'); __PACKAGE__->result_source_instance->is_virtual(1); __PACKAGE__->result_source_instance->view_definition( "SELECT posts.user_id, users.username, users.dob, users.realname, posts.createddate, posts.title, posts.post FROM users JOIN posts ON (users.id = posts.user_id)" ); __PACKAGE__->add_columns( user_id => { data_type => 'integer', }, username => { data_type => 'varchar', size => 255, }, dob => { data_type => 'date', }, realname => { data_type => 'varchar', size => 255, }, created_date => { data_type => 'datetime', }, title => { data_type => 'varchar', size => 255, }, post => { data_type => 'text', }, ); __PACKAGE__->set_primary_key('user_id, post_id'); =head3 CREATE INDEX =head4 UNIQUE indexes CREATE UNIQUE INDEX username_idx ON user (username); To add extra unique indexes, add the B call to your Result Class. __PACKAGE__->add_unique_constraint('username_idx' => ['username']); =head3 Outputting SQL Once the DBIC schema has been defined, you can outout the SQL needed to create the schema in the database in one of several ways. =head4 Deploy directly to the database Create a schema object with the correct database connection, then call B on it. my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); $schema->deploy({add_drop_table => 1}); L has the documentation for the deploy method. =head4 Write out SQL files Create a schema object with the a database connection (any will do), and call the B on it. my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); $schema->create_ddl_dir(['SQLite', 'MySQL']); By default this will create an SQL file for MySQL, PostgreSQL and SQLite. More databases are supported by L if necessary. =head4 SQL files for upgrades (ALTER TABLE) DBIC can also make use of L to write out ALTER TABLE statements when the schema classes are change. To do this, make sure that you set a B<$VERSION> in your main Schema class, and run B on the initial version to provide a baseline. After the schema has changed, change the B<$VERSION> value and re-run B. my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); $schema->create_ddl_dir(\@databases, undef, '.', '0.1');