Thread: Re: [SQL] Urgent help in bit_string data type

Re: [SQL] Urgent help in bit_string data type

From
Karthikeyan Sundaram
Date:
Joe,
 
  The reason why I am asking is, we are building an interface layer where all our users will have a view.  They shouldn't know anything about how and where the data is stored in the table.  They can be seen only by the portal which will use view.
 
    That's the reason.
 
Regards
skarthi

> Date: Wed, 11 Apr 2007 19:00:23 -0400
> From: dev@freedomcircle.net
> Subject: Re: [ADMIN] [SQL] Urgent help in bit_string data type
> To: skarthi98@hotmail.com
> CC: pgsql-admin@postgresql.org; pgsql-sql@postgresql.org
>
> Hi skarthi,
>
> On Wed, 2007-04-11 at 15:01 -0700, Karthikeyan Sundaram wrote:
> > create table test_a (b bit(3));
> >
> > create view test_vw (b1, b2, b3)
> > as select
> > to_number(substring(b,1,1)::int,'9') as b1,
> > to_number(substring(b,2,1)::int,'9') as b2,
> > to_number(substring(b,3,1)::int,'9') as b3 from test_a;
> >
> > create or replace rule test_a_ins as on insert to test_vw
> > do instead
> > insert into test_a (b) values (COALESCE(new.b1::bit,'1')||
> > COALESCE(new.b2::bit,'0')||COALESCE(new.b3::bit,'0')::bit);
> >
> > ERROR: cannot cast type numeric to bit
> >
> > How will I resolve this?
>
> *My* question is why are you doing such convoluted conversions, from bit
> string to text, then to int, etc.? It seems to me like you want to
> manipulate bits and if that's the case, you should be using the bit
> string operators, as someone pointed out a couple of days ago. In case
> you haven't looked at them, please see:
>
> http://www.postgresql.org/docs/8.2/static/functions-bitstring.html
>
> Joe
>
>
> ---------------------------(end of broadcast)---------------------------
> TIP 6: explain analyze is your friend



Live Search Maps – find all the local information you need, right when you need it. Find it!

Re: [SQL] Urgent help in bit_string data type

From
Joe
Date:
Hi skarthi,

On Wed, 2007-04-11 at 16:29 -0700, Karthikeyan Sundaram wrote:
>   The reason why I am asking is, we are building an interface layer
> where all our users will have a view.  They shouldn't know anything
> about how and where the data is stored in the table.  They can be seen
> only by the portal which will use view.
>
>     That's the reason.

I can understand using views to hide data from users, but that was not
what I was asking about.  It seems that you still have not read the page
that we referenced.  Consider the following:

test=> create table test_a (b bit(3));
CREATE TABLE
test=> insert into test_a values (b'001');
INSERT 0 1
test=> insert into test_a values (b'010');
INSERT 0 1
test=> insert into test_a values (b'101');
INSERT 0 1
test=> select * from test_a;
  b
-----
 001
 010
 101
(3 rows)

test=> create or replace view test_vw as
test-> select b::bit(1) as b2, (b<<1)::bit(1) as b1,
test-> (b<<2)::bit(1) as b0 from test_a;
CREATE VIEW
test=> select * from test_vw;
 b2 | b1 | b0
----+----+----
 0  | 0  | 1
 0  | 1  | 0
 1  | 0  | 1
(3 rows)

The view above gives the same results as your original view, but only
uses bit manipulations (and the only counterintuitive part is ::bit(1)
gives you the MSB).  Your view has to convert a bit string to text (or
maybe bytea) for the substring function, then it has to convert the text
to int because of your explicit cast, and finally it has to convert back
to text for the to_number function.  The result of to_number is numeric
and you're trying to cast it to bit, which is what the ERROR was telling
you can't do.

Joe