Home > Articles > Software Development & Management

Framework Design Guidelines: Data Source Architectural Patterns

Martin Fowler discusses data source architectural patterns, including Table Data Gateway, Row Data Gateway, Active Record and Data Mapper.
This chapter is from the book

Table Data Gateway

An object that acts as a Gateway (466) to a database table. One instance handles all the rows in the table.

Mixing SQL in application logic can cause several problems. Many developers aren't comfortable with SQL, and many who are comfortable may not write it well. Database administrators need to be able to find SQL easily so they can figure out how to tune and evolve the database.

A Table Data Gateway holds all the SQL for accessing a single table or view: selects, inserts, updates, and deletes. Other code calls its methods for all interaction with the database.

How It Works

A Table Data Gateway has a simple interface, usually consisting of several find methods to get data from the database and update, insert, and delete methods. Each method maps the input parameters into a SQL call and executes the SQL against a database connection.The Table Data Gateway is usually stateless, as its role is to push data back and forth.

The trickiest thing about a Table Data Gateway is how it returns information from a query. Even a simple find-by-ID query will return multiple data items. In environments where you can return multiple items you can use that for a single row, but many languages give you only a single return value and many queries return multiple rows.

One alternative is to return some simple data structure, such as a map. A map works, but it forces data to be copied out of the record set that comes from the database into the map. I think that using maps to pass data around is bad form because it defeats compile time checking and isn't a very explicit interface, leading to bugs as people misspell what's in the map. A better alternative is to use a Data Transfer Object (401). It's another object to create but one that may well be used elsewhere.

To save all this you can return the Record Set (508) that comes from the SQL query. This is conceptually messy, as ideally the in-memory object doesn't have to know anything about the SQL interface. It may also make it difficult to substitute the database for a file if you can't easily create record sets in your own code. Nevertheless, in many environments that use Record Set (508) widely, such as .NET, it's a very effective approach. A Table Data Gateway thus goes very well with Table Module (125). If all of your updates are done through the Table Data Gateway, the returned data can be based on views rather than on the actual tables, which reduces the coupling between your code and the database.

If you're using a Domain Model (116), you can have the Table Data Gateway return the appropriate domain object. The problem with this is that you then have bidirectional dependencies the domain objects and the gateway. The two are closely connected, so that isn't necessarily a terrible thing, but it's something I'm always reluctant to do.

Most times when you use Table Data Gateway, you'll have one for each table in the database. For very simple cases, however, you can have a single Table Data Gateway that handles all methods for all tables. You can also have one for views or even for interesting queries that aren't kept in the database as views. Obviously, view-based Table Data Gateways often can't update and so won't have update behavior. However, if you can make updates to the underlying tables, then encapsulating the updates behind update operations on the Table Data Gateway is a very good technique.

When to Use It

As with Row Data Gateway (152) the decision regarding Table Data Gateway is first whether to use a Gateway (466) approach at all and then which one.

I find that Table Data Gateway is probably the simplest database interface pattern to use, as it maps so nicely onto a database table or record type. It also makes a natural point to encapsulate the precise access logic of the data source. I use it least with Domain Model (116) because I find that Data Mapper (165) gives a better isolation between the Domain Model (116) and the database.

Table Data Gateway works particularly well with Table Module (125), where it produces a record set data structure for the Table Module (125) to work on. Indeed, I can't really imagine any other database-mapping approach for Table Module (125).

Just like Row Data Gateway (152), Table Data Gateway is very suitable for Transaction Scripts (110). The choice between the two really boils down to how they deal with multiple rows of data. Many people like using a Data Transfer Object (401), but that seems to me like more work than is worthwhile, unless the same Data Transfer Object (401) is used elsewhere. I prefer Table Data Gateway when the result set representation is convenient for the Transaction Script (110) to work with.

Interestingly, it often makes sense to have the Data Mappers (165) talk to the database via Table Data Gateways. Although this isn't useful when everything is handcoded, it can be very effective if you want to use metadata for the Table Data Gateways but prefer handcoding for the actual mapping to the domain objects.

One of the benefits of using a Table Data Gateway to encapsulate database access is that the same interface can work both for using SQL to manipulate the database and for using stored procedures. Indeed, stored procedures themselves are often organized as Table Data Gateways. That way the insert and update stored procedures encapsulate the actual table structure. The find procedures in this case can return views, which helps to hide the underlying table structure.

Further Reading

[Alur et al.] discusses the Data Access Object pattern, which is a Table Data Gateway. They show returning a collection of Data Transfer Objects (401) on the query methods. It's not clear whether they see this pattern as always being table based; the intent and discussion seems to imply either Table Data Gateway or Row Data Gateway (152).

I've used a different name, partly because I see this pattern as a particular usage of the more general Gateway (466) concept and I want the pattern name to reflect that. Also, the term Data Access Object and its abbreviation DAO has its own particular meaning within the Microsoft world.

Example: Person Gateway (C#)

Table Data Gateway is the usual form of database access in the windows world, so it makes sense to illustrate one with C#. I have to stress, however, that this classic form of Table Data Gateway doesn't quite fit in the .NET environment since it doesn't take advantage of the ADO.NET data set; instead, it uses the data reader, which is a cursor-like interface to database records. The data reader is the right choice for manipulating larger amounts of information when you don't want to bring everything into memory in one go.

For the example I'm using a Person Gateway class that connects to a person table in a database. The Person Gateway contains the finder code, returning ADO.NET's data reader to access the returned data.

class PersonGateway... 

      public IDataReader FindAll() {
         String sql = "select * from person";
         return new OleDbCommand(sql, DB.Connection).ExecuteReader();
      }
      public IDataReader FindWithLastName(String lastName) {
         String sql = "SELECT * FROM person WHERE lastname = ?";
         IDbCommand comm = new OleDbCommand(sql, DB.Connection);
         comm.Parameters.Add(new OleDbParameter("lastname", lastName));
         return comm.ExecuteReader();
      }
      public IDataReader FindWhere(String whereClause) {
         String sql = String.Format("select * from person where {0}", whereClause);
         return new OleDbCommand(sql, DB.Connection).ExecuteReader();
      }

Almost always you'll want to pull back a bunch of rows with a reader. On a rare occasion you might want to get hold of an individual row of data with a method along these lines:

class PersonGateway... 

      public Object[] FindRow (long key) {
         String sql = "SELECT * FROM person WHERE id = ?";
         IDbCommand comm = new OleDbCommand(sql, DB.Connection);
         comm.Parameters.Add(new OleDbParameter("key",key));
         IDataReader reader = comm.ExecuteReader();
         reader.Read();
         Object [] result = new Object[reader.FieldCount];
         reader.GetValues(result);
         reader.Close();
         return result;
      }

The update and insert methods receive the necessary data in arguments and invoke the appropriate SQL routines.

class PersonGateway... 

      public void Update (long key, String lastname, String firstname, long numberOfDependents){
            String sql = @"
               UPDATE person
                  SET lastname = ?, firstname = ?, numberOfDependents = ?
                  WHERE id = ?";
         IDbCommand comm = new OleDbCommand(sql, DB.Connection);
         comm.Parameters.Add(new OleDbParameter ("last", lastname));
         comm.Parameters.Add(new OleDbParameter ("first", firstname));
         comm.Parameters.Add(new OleDbParameter ("numDep", numberOfDependents));
         comm.Parameters.Add(new OleDbParameter ("key", key));
         comm.ExecuteNonQuery();
      }

class PersonGateway...

      public long Insert(String lastName, String firstName, long numberOfDependents) {
         String sql = "INSERT INTO person VALUES (?,?,?,?)";
         long key = GetNextID();
         IDbCommand comm = new OleDbCommand(sql, DB.Connection);
         comm.Parameters.Add(new OleDbParameter ("key", key));
         comm.Parameters.Add(new OleDbParameter ("last", lastName));
         comm.Parameters.Add(new OleDbParameter ("first", firstName));
         comm.Parameters.Add(new OleDbParameter ("numDep", numberOfDependents));
         comm.ExecuteNonQuery();
         return key;
      }

The deletion method just needs a key.

class PersonGateway... 

      public void Delete (long key) {
         String sql = "DELETE FROM person WHERE id = ?";
         IDbCommand comm = new OleDbCommand(sql, DB.Connection);
         comm.Parameters.Add(new OleDbParameter ("key", key));
         comm.ExecuteNonQuery();
      }

Example: Using ADO.NET Data Sets (C#)

The generic Table Data Gateway works with pretty much any kind of platform since it's nothing but a wrapper for SQL statements. With .NET you use data sets more often, but Table Data Gateway is still useful although it comes in a different form.

A data set needs data adapters to load the data into it and update the data. In find it useful to define a holder for the data set and the adapters. A gateway then uses the holder to store them. Much of this behavior is generic and can be done in a superclass.

The holder indexes the data sets and adapters by the name of the table.

class DataSetHolder... 

      public DataSet Data = new DataSet();
      private Hashtable DataAdapters = new Hashtable();

The gateway stores the holder and exposes the data set for its clients.

class DataGateway... 

      public DataSetHolder Holder;
      public DataSet Data {
         get {return Holder.Data;}
      }

The gateway can act on an existing holder, or it can create a new one.

class DataGateway... 

      protected DataSetGateway() {
         Holder = new DataSetHolder();
      }
      protected DataSetGateway(DataSetHolder holder) {
         this.Holder = holder;
      }

The find behavior can work a bit differently here. A data set is a container for table-oriented data and can hold data from several tables. For that reason it's better to load data into a data set.

class DataGateway... 

      public void LoadAll() {
         String commandString = String.Format("select * from {0}", TableName);
         Holder.FillData(commandString, TableName);
      }
      public void LoadWhere(String whereClause) {
         String commandString =
            String.Format("select * from {0}where {1}", TableName,whereClause);
         Holder.FillData(commandString, TableName);
      }
      abstract public String TableName {get;}

class PersonGateway...

      public override String TableName {
         get {return "Person";}
      }

class DataSetHolder...

      public void FillData(String query, String tableName) {
         if (DataAdapters.Contains(tableName)) throw new MutlipleLoadException();
         OleDbDataAdapter da = new OleDbDataAdapter(query, DB.Connection);
         OleDbCommandBuilder builder = new OleDbCommandBuilder(da);
         da.Fill(Data, tableName);
         DataAdapters.Add(tableName, da);
      }

To update data you manipulate the data set directly in some client code.

person.LoadAll(); 
person[key]["lastname"] = "Odell";
person.Holder.Update();

The gateway can have an indexer to make it easier to get to specific rows.

class DataGateway... 

      public DataRow this[long key] {
         get {
            String filter = String.Format("id = {0}", key);
            return Table.Select(filter)[0];
         }
      }
      public override DataTable Table {
         get {return Data.Tables[TableName];}
      }

The update triggers update behavior on the holder.

class DataSetHolder... 

      public void Update() {
         foreach (String table in DataAdapters.Keys)
             ((OleDbDataAdapter)DataAdapters[table]).Update(Data, table);
      }
      public DataTable this[String tableName] {
         get {return Data.Tables[tableName];}
      }

Insertion can be done much the same way: Get a data set, insert a new row in the data table, and fill in each column. However, an update method can do the insertion in one call.

class DataGateway... 

      public long Insert(String lastName, String firstname, int numberOfDependents) {
         long key = new PersonGatewayDS().GetNextID();
         DataRow newRow = Table.NewRow();
         newRow["id"] = key;
         newRow["lastName"] = lastName;
         newRow["firstName"] = firstname;
         newRow["numberOfDependents"] = numberOfDependents;
         Table.Rows.Add(newRow);
         return key;
      }

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020