Thread: performance cost for varchar(20), varchar(255), and text

performance cost for varchar(20), varchar(255), and text

From
Jessica Richard
Date:
I am tuning a database created by someone else.

I noticed that some column lengths were defined longer than needed.

For example, an Id column is holding a stand length of 20 characters but was defined as varchar(255).

On some other columns, for example, a Description column is supposed to hold less than 100 characters but defined as text.

I am trying to understand the performance impact if a column is over defined in the following cases:

1. char(20) vs varchar(20)

2. varchar(20) vs varchar(255)

3. varchar(255) vs text


thanks,
Jessica

Re: performance cost for varchar(20), varchar(255), and text

From
Shane Ambler
Date:
Jessica Richard wrote:
> I am tuning a database created by someone else.
>
> I noticed that some column lengths were defined longer than needed.
>
> For example, an Id column is holding a stand length of 20 characters
> but was defined as varchar(255).
>
> On some other columns, for example, a Description column is supposed
> to hold less than 100 characters but defined as text.
>
> I am trying to understand the performance impact if a column is over
> defined in the following cases:
>
> 1. char(20) vs varchar(20)
>
> 2. varchar(20) vs varchar(255)
>
> 3. varchar(255) vs text
>
>
> thanks, Jessica
>

 From the manual -
<quote>
Tip: There are no performance differences between these three types,
apart from increased storage size when using the blank-padded type, and
a few extra cycles to check the length when storing into a
length-constrained column. While character(n) has performance advantages
in some other database systems, it has no such advantages in PostgreSQL.
In most situations text or character varying should be used instead.
</quote>

http://www.postgresql.org/docs/8.3/static/datatype-character.html


--

Shane Ambler
pgSQL (at) Sheeky (dot) Biz

Get Sheeky @ http://Sheeky.Biz

Re: performance cost for varchar(20), varchar(255), and text

From
Lew
Date:
Jessica Richard wrote:
> I am tuning a database created by someone else.
>
> I noticed that some column lengths were defined longer than needed.
>
> For example, an Id column is holding a stand length of 20 characters but
> was defined as varchar(255).
>
> On some other columns, for example, a Description column is supposed to
> hold less than 100 characters but defined as text.
>
> I am trying to understand the performance impact if a column is over
> defined in the following cases:
>
> 1. char(20) vs varchar(20)
>
> 2. varchar(20) vs varchar(255)
>
> 3. varchar(255) vs text

Interestingly, the Postgres documentation has the answer:
<http://www.postgresql.org/docs/8.3/interactive/datatype-character.html>
> Tip:  There are no performance differences between these three types, apart
> from increased storage size when using the blank-padded type, and a few extra
> cycles to check the length when storing into a length-constrained column.
> While character(n) has performance advantages in some other database systems,
> it has no such advantages in PostgreSQL. In most situations text or character
> varying should be used instead.

Performance is not the only issue.  The semantics of CHAR and VARCHAR differ.
  You cannot use them equivalently.

I recommend searching the docs as a first approach to finding such answers.

--
Lew