Thread: Celko's Puzzle Number 5

Celko's Puzzle Number 5

From
Richard Broersma Jr
Date:
No matter how I try it, I can't getting the book's answer for this puzzle to work.  Does anyone
know of a solution that will work for this problem.  

The Problem is:
"How do you ensure that a column will have a single alphabetic character string in it? (That means
no spaces, no numbers, and no special characters.)"

The book's solution is as follows:

CREATE TABLE Foobar
(alpha_only VARCHAR(6)           CHECK ((UPPER(TRIM(alpha_only)) || 'AAAAA')                  BETWEEN 'AAAAAA' AND
'ZZZZZZ')
);

However,  this check constraint only prevents numerics beginning with 'A'.
So the constraint works by preventing following strings that begin with these kinds of characters:
!....,
4....,
A!...,
A4...

But the constraint fails to prevent non-alphabetic characters when the string starts with a
character  > A.  Thus B thru Z can be follow on not alphabetic characters.

I compared the result from PostgreSQL with sqlite and access.  They returned the same result. 
According to the text, this solution "could" have been generalized to work with more complicated
strings as well.  For example string "masks" could be used to enforce a kind of tagging conventionlike 'AA44444',
'BB55555'.

Has anyone seen or done anything like this before?

I am interested to hear what kind of solutions there are.

Regards,

Richard Broersma Jr. 


Re: Celko's Puzzle Number 5

From
Michael Fuhr
Date:
On Fri, Jul 07, 2006 at 11:34:57PM -0700, Richard Broersma Jr wrote:
> "How do you ensure that a column will have a single alphabetic
> character string in it? (That means no spaces, no numbers, and
> no special characters.)"

You can check patterns with regular expressions.  PostgreSQL supports
SIMILAR TO, which is standard SQL since SQL:1999, and POSIX regular
expressions; see "Pattern Matching" in the "Functions and Operators"
chapter of the documentation:

http://www.postgresql.org/docs/8.1/interactive/functions-matching.html

Any of these CHECK expressions should work:
 CHECK (alpha_only SIMILAR TO '[A-Za-z]+') CHECK (alpha_only ~ '^[A-Za-z]+$') CHECK (alpha_only ~* '^[a-z]+$')

Unfortunately, even though SIMILAR TO has been standard SQL for
several years, not all databases implement it.  Many databases
do support regular expressions but generally via a non-standard
syntax (as PostgreSQL does with its ~, ~*, !*, and !~*  operators).

-- 
Michael Fuhr


Re: Celko's Puzzle Number 5

From
Richard Broersma Jr
Date:
> http://www.postgresql.org/docs/8.1/interactive/functions-matching.html
> 
> Any of these CHECK expressions should work:
> 
>   CHECK (alpha_only SIMILAR TO '[A-Za-z]+')
>   CHECK (alpha_only ~ '^[A-Za-z]+$')
>   CHECK (alpha_only ~* '^[a-z]+$')
> 
> Unfortunately, even though SIMILAR TO has been standard SQL for
> several years, not all databases implement it.  Many databases
> do support regular expressions but generally via a non-standard
> syntax (as PostgreSQL does with its ~, ~*, !*, and !~*  operators).

Thanks for the link!

Regards,

Richard Broersma Jr.