Re: High level discussion for design of using ACL to retrieve Data

Поиск
Список
Период
Сортировка
От Joel Fradkin
Тема Re: High level discussion for design of using ACL to retrieve Data
Дата
Msg-id 000e01c5e6c9$985269c0$797ba8c0@jfradkin
обсуждение исходный текст
Ответ на High level discussion for design of using ACL to retrieve Data  ("Joel Fradkin" <jfradkin@wazagua.com>)
Список pgsql-sql

I had an offlist inquiry for more details so I thought I would post my response.

This is a select using the union for auto xref.

 

SELECT distinct * FROM (

 select * from viwcaselist where clientnum = 'SEA' AND DivisionID = 100 And isdeleted=false

union all

select * from viwcaselist where clientnum = 'SEA' And isdeleted=false and MainLocationID IN (SELECT AutoLocationID FROM tblSearsAutoXref WHERE (LocationID in ( select MainLocationID from viwLocationWDivRegDis where clientnum = 'SEA' AND DivisionID = 100)))

) DERIVEDTBL Order BY OpenDate Desc,CaseNum limit 51

 

Normaly it is more like.

 

select * from viwcaselist where clientnum = 'WAZ' AND DivisionID = 100 And isdeleted=false Order BY OpenDate Desc,CaseNum limit 51

 

We have location,district, region, and division tables.

AND DivisionID = 100 is the key for getting the records (this changes based on the user level can be district, region, division, or location, or all records fro company level).

 

What I would like to see is the ability to have more types of access to the data then one level, but as you can see from the xref I implemented it runs super slow compared to just a straight select. I made a view  viwLocationWDivRegDis that has the four tables (div,reg,dist,loc) tied together with joins.

 

Our location table :

CREATE TABLE tbllocation

(

  clientnum varchar(16) NOT NULL,

  locationid int4 NOT NULL,

  districtid int4 NOT NULL,

  regionid int4 NOT NULL,

  divisionid int4 NOT NULL,

  locationnum varchar(8),

  name varchar(50),

  clientlocnum varchar(50),

  address varchar(100),

  address2 varchar(100),

  city varchar(50),

  state varchar(2) NOT NULL DEFAULT 'zz'::character varying,

  zip varchar(10),

  countryid int4,

  phone varchar(15),

  fax varchar(15),

  payname varchar(40),

  contact char(36),

  active bool NOT NULL DEFAULT true,

  coiprogram text,

  coilimit text,

  coiuser varchar(255),

  coidatetime varchar(32),

  ec_note_field varchar(1050),

  locationtypeid int4,

  open_time timestamp,

  close_time timestamp,

  insurance_loc_id varchar(50),

  lpregionid int4,

  sic int4,

  exportentity varchar(16),

  CONSTRAINT pk_tbllocation PRIMARY KEY (clientnum, locationid),

  CONSTRAINT ix_tbllocation_1 UNIQUE (clientnum, locationnum, name),

  CONSTRAINT ix_tbllocation_unique_number UNIQUE (clientnum, divisionid, regionid, districtid, locationnum)

)

WITH OIDS;

 

 

CREATE OR REPLACE VIEW viwlocationwdivregdis AS

 SELECT tbllocation.clientnum, tbllocation.locationid, tbllocation.locationnum, tbllocation.name, tbldivision.divisionnum, tbldivision.divisionname, tblregion.regionnum, tblregion.regionname, tbldistrict.districtnum, tbldistrict.districtname, tbllocation.locationid AS mainlocationid, tbllocation.divisionid, tbllocation.regionid, tbllocation.districtid, tbllocation.phone, tbllocation.contact, tbllocation.active, tbldistrict.active AS distactive, tblregion.active AS regactive, tbldivision.active AS divactive

   FROM tbllocation

   JOIN tbldivision ON tbllocation.clientnum::text = tbldivision.clientnum::text AND tbllocation.divisionid = tbldivision.divisionid

   JOIN tblregion ON tbllocation.clientnum::text = tblregion.clientnum::text AND tbllocation.regionid = tblregion.regionid AND tbllocation.divisionid = tblregion.divisionid

   JOIN tbldistrict ON tbllocation.clientnum::text = tbldistrict.clientnum::text AND tbllocation.regionid = tbldistrict.regionid AND tbllocation.divisionid = tbldistrict.divisionid AND tbllocation.districtid = tbldistrict.districtid;

 

Any ideas would be great!

 

 

 

Joel Fradkin

 

 

-----Original Message-----
From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] On Behalf Of
Joel Fradkin
Sent: Thursday, November 10, 2005 3:19 PM
To:
pgsql-sql@postgresql.org
Subject: [SQL] High level discussion for design of using ACL to retrieve Data

 

We currently use a system with 4 tables (division, region, district, location).

The data for the most part has a field named location id.

The users get a level and location id (if they are district it would represent a district id etc).

 

I have been asked to make this more flexible, for example if the user needs data for two locations but they are not in the same district.

 

One thing I have had to add was the ability to have a user have access to a location and then also have access to a related location (main and auto center have different location number, but if the user has access to the main location he can also see auto center data).

 

I did this with a xref table and a union, but it seem pretty slow.

So adding even more flexibity like multiple districts, locs etc (was thinking of trying to do some kind of grouping that would encompass our current plan) has been a problem I have thought about a lot, but I have not figured out a way that will give fast access.

I could do groups of access rights and do unions with distinct to get data, but I fear that would be really slow.

 

Any one have ideas on this subject?

 

Thanks in advance.

 

Joel Fradkin

 


 

 

В списке pgsql-sql по дате отправления:

Предыдущее
От: "Gregory S. Williamson"
Дата:
Сообщение: Re: Como ejecutar una funcion insert en plpgsql....
Следующее
От: Harald Fuchs
Дата:
Сообщение: Re: how to update table to make dup values distinct