====== Postgres als Backend für OpenLDAP ====== ===== Vorraussetzung ===== Postgres Server installiert und über localhost erreichbar ===== Debian 6.0 ===== Pakete: ''odbc-postgresql unixodbc slapd'' Als Nutzer apt-get source slapd ===== Postgres User und Datenbank anlegen ===== su - postgres createuser -SDRP pgldap createdb -E utf8 -O pgldap pgldap exit Als Nutzer psql pgldap pgldap < ./openldap-2.4.23/servers/slapd/back-sql/rdbms_depend/pgsql/backsql_create.sql psql pgldap pgldap < ./openldap-2.4.23/servers/slapd/back-sql/rdbms_depend/pgsql/testdb_create.sql psql pgldap pgldap < ./openldap-2.4.23/servers/slapd/back-sql/rdbms_depend/pgsql/testdb_data.sql psql pgldap pgldap < ./openldap-2.4.23/servers/slapd/back-sql/rdbms_depend/pgsql/testdb_metadata.sql ''backsql_create.sql'' : drop table ldap_oc_mappings; drop sequence ldap_oc_mappings_id_seq; create table ldap_oc_mappings ( id serial not null primary key, name varchar(64) not null, keytbl varchar(64) not null, keycol varchar(64) not null, create_proc varchar(255), delete_proc varchar(255), expect_return int not null ); drop table ldap_attr_mappings; drop sequence ldap_attr_mappings_id_seq; create table ldap_attr_mappings ( id serial not null primary key, oc_map_id integer not null references ldap_oc_mappings(id), name varchar(255) not null, sel_expr varchar(255) not null, sel_expr_u varchar(255), from_tbls varchar(255) not null, join_where varchar(255), add_proc varchar(255), delete_proc varchar(255), param_order int not null, expect_return int not null ); drop table ldap_entries; drop sequence ldap_entries_id_seq; create table ldap_entries ( id serial not null primary key, dn varchar(255) not null, oc_map_id integer not null references ldap_oc_mappings(id), parent int NOT NULL, keyval int NOT NULL, UNIQUE ( oc_map_id, keyval ), UNIQUE ( dn ) ); drop table ldap_entry_objclasses; create table ldap_entry_objclasses ( entry_id integer not null references ldap_entries(id), oc_name varchar(64) ); ''testdb_create.sql'' : drop table persons; drop sequence persons_id_seq; create table persons ( id serial not null primary key, name varchar(255) not null, surname varchar(255) not null, password varchar(64) ); drop table institutes; drop sequence institutes_id_seq; create table institutes ( id serial not null primary key, name varchar(255) ); drop table documents; drop sequence documents_id_seq; create table documents ( id serial not null primary key, title varchar(255) not null, abstract varchar(255) ); drop table authors_docs; create table authors_docs ( pers_id int not null, doc_id int not null, primary key ( pers_id, doc_id ) ); drop table phones; drop sequence phones_id_seq; create table phones ( id serial not null primary key, phone varchar(255) not null , pers_id int not null ); drop table certs; drop sequence certs_id_seq; CREATE TABLE certs ( id int not null primary key, cert bytea not null, pers_id int not null ); drop table referrals; drop sequence referrals_id_seq; create table referrals ( id serial not null primary key, name varchar(255) not null, url varchar(255) not null ); ''testdb_data.sql'' : insert into institutes (id,name) values (1,'Example'); insert into persons (id,name,surname,password) values (1,'Mitya','Kovalev','mit'); insert into persons (id,name,surname) values (2,'Torvlobnor','Puzdoy'); insert into persons (id,name,surname) values (3,'Akakiy','Zinberstein'); insert into phones (id,phone,pers_id) values (1,'332-2334',1); insert into phones (id,phone,pers_id) values (2,'222-3234',1); insert into phones (id,phone,pers_id) values (3,'545-4563',2); insert into documents (id,abstract,title) values (1,'abstract1','book1'); insert into documents (id,abstract,title) values (2,'abstract2','book2'); insert into authors_docs (pers_id,doc_id) values (1,1); insert into authors_docs (pers_id,doc_id) values (1,2); insert into authors_docs (pers_id,doc_id) values (2,1); insert into referrals (id,name,url) values (1,'Referral','ldap://localhost:9012/'); insert into certs (id,cert,pers_id) values (1,decode('MIIDazCCAtSgAwIBAgIBAjANBgkqhkiG9w0BAQQFADB3MQswCQYDVQQGEwJVUzETMBEGA1UECBMKQ2FsaWZvcm5pYTEfMB0GA1UEChMWT3BlbkxEQVAgRXhhbXBsZSwgTHRkLjETMBEGA1UEAxMKRXhhbXBsZSBDQTEdMBsGCSqGSIb3DQEJARYOY2FAZXhhbXBsZS5jb20wHhcNMDMxMDE3MTYzMzE5WhcNMDQxMDE2MTYzMzE5WjB+MQswCQYDVQQGEwJVUzETMBEGA1UECBMKQ2FsaWZvcm5pYTEfMB0GA1UEChMWT3BlbkxEQVAgRXhhbXBsZSwgTHRkLjEYMBYGA1UEAxMPVXJzdWxhIEhhbXBzdGVyMR8wHQYJKoZIhvcNAQkBFhB1aGFtQGV4YW1wbGUuY29tMIGfMA0GCSqGSIb3DQEBAQUAA4GNADCBiQKBgQDuxgp5ELV9LmhxWMpV7qc4028QQT3+zzFDXhruuXE7ji2n3S3ea8bOwDtJh+qnsDe561DhHHHlgIjMKCiDEizYMpxvJPYEXmvp0huRkMgpKZgmel95BSkt6TYmJ0erS3aoimOHLEFimmnTLolNRMiWqNBvqwobx940PGwUWEePKQIDAQABo4H/MIH8MAkGA1UdEwQCMAAwLAYJYIZIAYb4QgENBB8WHU9wZW5TU0wgR2VuZXJhdGVkIENlcnRpZmljYXRlMB0GA1UdDgQWBBSjI94TbBmuDEeUUOiC37EK0Uf0XjCBoQYDVR0jBIGZMIGWgBRLbyEaNiTSkPlDsFNHLX3hwOaYI6F7pHkwdzELMAkGA1UEBhMCVVMxEzARBgNVBAgTCkNhbGlmb3JuaWExHzAdBgNVBAoTFk9wZW5MREFQIEV4YW1wbGUsIEx0ZC4xEzARBgNVBAMTCkV4YW1wbGUgQ0ExHTAbBgkqhkiG9w0BCQEWDmNhQGV4YW1wbGUuY29tggEAMA0GCSqGSIb3DQEBBAUAA4GBAIgUcARb3OlWYNbmr1nmqESuxLn16uqI1Ot6WkcICvpkdQ+Bo+R9AP05xpoXocZtKdNvBu3FNxB/jFkiOcLU2lX7Px1Ijnsjh60qVRy9HOsHCungIKlGcnXLKHmKu0y//5jds/HnaJsGcHI5JRG7CBJbW+wrwge3trJ1xHJI8prN','base64'),3); ''testdb_metadata.sql'' : -- mappings -- objectClass mappings: these may be viewed as structuralObjectClass, the ones that are used to decide how to build an entry -- id a unique number identifying the objectClass -- name the name of the objectClass; it MUST match the name of an objectClass that is loaded in slapd's schema -- keytbl the name of the table that is referenced for the primary key of an entry -- keycol the name of the column in "keytbl" that contains the primary key of an entry; the pair "keytbl.keycol" uniquely identifies an entry of objectClass "id" -- create_proc a procedure to create the entry -- delete_proc a procedure to delete the entry; it takes "keytbl.keycol" of the row to be deleted -- expect_return a bitmap that marks whether create_proc (1) and delete_proc (2) return a value or not insert into ldap_oc_mappings (id,name,keytbl,keycol,create_proc,delete_proc,expect_return) values (1,'inetOrgPerson','persons','id','SELECT create_person()','DELETE FROM persons WHERE id=?',0); insert into ldap_oc_mappings (id,name,keytbl,keycol,create_proc,delete_proc,expect_return) values (2,'document','documents','id','SELECT create_doc()','DELETE FROM documents WHERE id=?',0); insert into ldap_oc_mappings (id,name,keytbl,keycol,create_proc,delete_proc,expect_return) values (3,'organization','institutes','id','SELECT create_o()','DELETE FROM institutes WHERE id=?',0); insert into ldap_oc_mappings (id,name,keytbl,keycol,create_proc,delete_proc,expect_return) values (4,'referral','referrals','id','SELECT create_referral()','DELETE FROM referrals WHERE id=?',0); -- attributeType mappings: describe how an attributeType for a certain objectClass maps to the SQL data. -- id a unique number identifying the attribute -- oc_map_id the value of "ldap_oc_mappings.id" that identifies the objectClass this attributeType is defined for -- name the name of the attributeType; it MUST match the name of an attributeType that is loaded in slapd's schema -- sel_expr the expression that is used to select this attribute (the "select from ..." portion) -- from_tbls the expression that defines the table(s) this attribute is taken from (the "select ... from where ..." portion) -- join_where the expression that defines the condition to select this attribute (the "select ... where ..." portion) -- add_proc a procedure to insert the attribute; it takes the value of the attribute that is added, and the "keytbl.keycol" of the entry it is associated to -- delete_proc a procedure to delete the attribute; it takes the value of the attribute that is added, and the "keytbl.keycol" of the entry it is associated to -- param_order a mask that marks if the "keytbl.keycol" value comes before or after the value in add_proc (1) and delete_proc (2) -- expect_return a mask that marks whether add_proc (1) and delete_proc(2) are expected to return a value or not insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (1,1,'cn','text(persons.name||'' ''||persons.surname)','persons',NULL,'SELECT update_person_cn(?,?)','SELECT 1 FROM persons WHERE persons.name=? AND persons.id=? AND 1=0',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (2,1,'telephoneNumber','phones.phone','persons,phones','phones.pers_id=persons.id','SELECT add_phone(?,?)','DELETE FROM phones WHERE phone=? AND pers_id=?',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (3,1,'givenName','persons.name','persons',NULL,'UPDATE persons SET name=? WHERE id=?','UPDATE persons SET name='''' WHERE (name=? OR name='''') AND id=?',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (4,1,'sn','persons.surname','persons',NULL,'UPDATE persons SET surname=? WHERE id=?','UPDATE persons SET surname='''' WHERE (surname=? OR surname='''') AND id=?',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (5,1,'userPassword','persons.password','persons','persons.password IS NOT NULL','UPDATE persons SET password=? WHERE id=?','UPDATE persons SET password=NULL WHERE password=? AND id=?',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (6,1,'seeAlso','seeAlso.dn','ldap_entries AS seeAlso,documents,authors_docs,persons','seeAlso.keyval=documents.id AND seeAlso.oc_map_id=2 AND authors_docs.doc_id=documents.id AND authors_docs.pers_id=persons.id',NULL,'DELETE from authors_docs WHERE authors_docs.doc_id=(SELECT documents.id FROM documents,ldap_entries AS seeAlso WHERE seeAlso.keyval=documents.id AND seeAlso.oc_map_id=2 AND seeAlso.dn=?) AND authors_docs.pers_id=?',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (7,2,'description','documents.abstract','documents',NULL,'UPDATE documents SET abstract=? WHERE id=?','UPDATE documents SET abstract='''' WHERE abstract=? AND id=?',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (8,2,'documentTitle','documents.title','documents',NULL,'UPDATE documents SET title=? WHERE id=?','UPDATE documents SET title='''' WHERE title=? AND id=?',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (9,2,'documentAuthor','documentAuthor.dn','ldap_entries AS documentAuthor,documents,authors_docs,persons','documentAuthor.keyval=persons.id AND documentAuthor.oc_map_id=1 AND authors_docs.doc_id=documents.id AND authors_docs.pers_id=persons.id','INSERT INTO authors_docs (pers_id,doc_id) VALUES ((SELECT ldap_entries.keyval FROM ldap_entries WHERE upper(?)=upper(ldap_entries.dn)),?)','DELETE FROM authors_docs WHERE authors_docs.pers_id=(SELECT ldap_entries.keyval FROM ldap_entries WHERE upper(?)=upper(ldap_entries.dn)) AND authors_docs.doc_id=?',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (10,2,'documentIdentifier','''document ''||text(documents.id)','documents',NULL,NULL,'SELECT 1 FROM documents WHERE title=? AND id=? AND 1=0',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (11,3,'o','institutes.name','institutes',NULL,'UPDATE institutes SET name=? WHERE id=?','UPDATE institutes SET name='''' WHERE name=? AND id=?',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (12,3,'dc','lower(institutes.name)','institutes,ldap_entries AS dcObject,ldap_entry_objclasses AS auxObjectClass','institutes.id=dcObject.keyval AND dcObject.oc_map_id=3 AND dcObject.id=auxObjectClass.entry_id AND auxObjectClass.oc_name=''dcObject''',NULL,'SELECT 1 FROM institutes WHERE lower(name)=? AND id=? and 1=0',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (13,4,'ou','referrals.name','referrals',NULL,'UPDATE referrals SET name=? WHERE id=?','SELECT 1 FROM referrals WHERE name=? AND id=? and 1=0',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (14,4,'ref','referrals.url','referrals',NULL,'UPDATE referrals SET url=? WHERE id=?','SELECT 1 FROM referrals WHERE url=? and id=? and 1=0',3,0); insert into ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where,add_proc,delete_proc,param_order,expect_return) values (15,1,'userCertificate','certs.cert','persons,certs','certs.pers_id=persons.id',NULL,NULL,3,0); -- entries mapping: each entry must appear in this table, with a unique DN rooted at the database naming context -- id a unique number > 0 identifying the entry -- dn the DN of the entry, in "pretty" form -- oc_map_id the "ldap_oc_mappings.id" of the main objectClass of this entry (view it as the structuralObjectClass) -- parent the "ldap_entries.id" of the parent of this objectClass; 0 if it is the "suffix" of the database -- keyval the value of the "keytbl.keycol" defined for this objectClass insert into ldap_entries (id,dn,oc_map_id,parent,keyval) values (1,'dc=example,dc=com',3,0,1); insert into ldap_entries (id,dn,oc_map_id,parent,keyval) values (2,'cn=Mitya Kovalev,dc=example,dc=com',1,1,1); insert into ldap_entries (id,dn,oc_map_id,parent,keyval) values (3,'cn=Torvlobnor Puzdoy,dc=example,dc=com',1,1,2); insert into ldap_entries (id,dn,oc_map_id,parent,keyval) values (4,'cn=Akakiy Zinberstein,dc=example,dc=com',1,1,3); insert into ldap_entries (id,dn,oc_map_id,parent,keyval) values (5,'documentTitle=book1,dc=example,dc=com',2,1,1); insert into ldap_entries (id,dn,oc_map_id,parent,keyval) values (6,'documentTitle=book2,dc=example,dc=com',2,1,2); insert into ldap_entries (id,dn,oc_map_id,parent,keyval) values (7,'ou=Referral,dc=example,dc=com',4,1,1); -- objectClass mapping: entries that have multiple objectClass instances are listed here with the objectClass name (view them as auxiliary objectClass) -- entry_id the "ldap_entries.id" of the entry this objectClass value must be added -- oc_name the name of the objectClass; it MUST match the name of an objectClass that is loaded in slapd's schema insert into ldap_entry_objclasses (entry_id,oc_name) values (1,'dcObject'); insert into ldap_entry_objclasses (entry_id,oc_name) values (4,'pkiUser'); insert into ldap_entry_objclasses (entry_id,oc_name) values (7,'extensibleObject'); -- procedures -- these procedures are specific for this RDBMS and are used in mapping objectClass and attributeType creation/modify/deletion create function create_person () returns int as ' select setval (''persons_id_seq'', (select case when max(id) is null then 1 else max(id) end from persons)); insert into persons (id,name,surname) values ((select case when max(id) is null then 1 else nextval(''persons_id_seq'') end from persons),'''',''''); select max(id) from persons ' language 'sql'; create function update_person_cn (varchar, int) returns int as ' update persons set name = ( select case when position('' '' in $1) = 0 then $1 else substr($1, 1, position('' '' in $1) - 1) end ),surname = ( select case when position('' '' in $1) = 0 then '''' else substr($1, position('' '' in $1) + 1) end ) where id = $2; select $2 as return ' language 'sql'; create function add_phone (varchar, int) returns int as ' select setval (''phones_id_seq'', (select case when max(id) is null then 1 else max(id) end from phones)); insert into phones (id,phone,pers_id) values (nextval(''phones_id_seq''),$1,$2); select max(id) from phones ' language 'sql'; create function create_doc () returns int as ' select setval (''documents_id_seq'', (select case when max(id) is null then 1 else max(id) end from documents)); insert into documents (id,title,abstract) values ((select case when max(id) is null then 1 else nextval(''documents_id_seq'') end from documents),'''',''''); select max(id) from documents ' language 'sql'; create function create_o () returns int as ' select setval (''institutes_id_seq'', (select case when max(id) is null then 1 else max(id) end from institutes)); insert into institutes (id,name) values ((select case when max(id) is null then 1 else nextval(''institutes_id_seq'') end from institutes),''''); select max(id) from institutes ' language 'sql'; create function create_referral () returns int as ' select setval (''referrals_id_seq'', (select case when max(id) is null then 1 else max(id) end from referrals)); insert into referrals (id,name,url) values ((select case when max(id) is null then 1 else nextval(''referrals_id_seq'') end from referrals),'''',''''); select max(id) from referrals ' language 'sql'; ===== unixODBC konfigurieren ===== odbcinst -i -d -f /usr/share/psqlodbc/odbcinst.ini.template erzeugt ''/etc/odbcinst.ini'' ''/etc/odbc.ini'' : [pgldap] Description = Example for OpenLDAP's back-sql Driver = PostgreSQL Unicode Trace = No Database = pgldap Servername = localhost UserName = pgldap Password = villa Port = 5432 ;Protocol = 6.4 ReadOnly = No RowVersioning = No ShowSystemTables = No ShowOidColumn = No FakeOidIndex = No ConnSettings = ==== testen ==== ODBC: isql pgldap pgldap select * from persons; quit ===== slapd ===== ''/etc/default/slapd'' : SLAPD_CONF=/etc/ldap/slapd.conf ''/etc/ldap/slapd.conf'' : include /etc/ldap/schema/core.schema include /etc/ldap/schema/cosine.schema include /etc/ldap/schema/nis.schema include /etc/ldap/schema/inetorgperson.schema pidfile /var/run/slapd/slapd.pid argsfile /var/run/slapd/slapd.args loglevel none modulepath /usr/lib/ldap moduleload back_sql.la moduleload back_monitor.la sizelimit 500 tool-threads 1 access to attrs=userpassword by self =w by anonymous =x access to * by * read backend sql database sql suffix "dc=example,dc=com" rootdn "cn=Manager,dc=example,dc=com" rootpw secret dbname pgldap dbuser pgldap dbpasswd villa insentry_stmt "insert into ldap_entries (id,dn,oc_map_id,parent,keyval) values ((select case when max(id) is null then 1 else max(id) + 1 end from ldap_entries),?,?,?,?)" upper_func "upper" strcast_func "text" concat_pattern "?||?" has_ldapinfo_dn_ru no database monitor ldapsearch -x -W -b dc=example,dc=com -H ldap://localhost -D cn=Manager,dc=example,dc=com ====== Postgres als read-only Backend für OpenLDAP ====== ===== Vorraussetzung ===== Postgres Server installiert und über localhost erreichbar ===== Debian 6.0 ===== Pakete: ''odbc-postgresql unixodbc slapd'' Als Nutzer apt-get source slapd ===== Postgres User und Datenbank anlegen ===== su - postgres createuser -SDRP pgldapro createdb -E utf8 -O pgldapro pgldapro exit ''testdb_create.sql'' : DROP TABLE persons; DROP sequence persons_id_seq; CREATE TABLE persons ( id serial NOT NULL PRIMARY KEY, name varchar(255) NOT NULL, surname varchar(255) NOT NULL, password varchar(64) ); DROP TABLE institutes; DROP sequence institutes_id_seq; CREATE TABLE institutes ( id serial NOT NULL PRIMARY KEY, name varchar(255) ); DROP TABLE documents; DROP sequence documents_id_seq; CREATE TABLE documents ( id serial NOT NULL PRIMARY KEY, title varchar(255) NOT NULL, abstract varchar(255) ); DROP TABLE authors_docs; CREATE TABLE authors_docs ( pers_id int NOT NULL, doc_id int NOT NULL, PRIMARY KEY ( pers_id, doc_id ) ); DROP TABLE phones; DROP sequence phones_id_seq; CREATE TABLE phones ( id serial NOT NULL PRIMARY KEY, phone varchar(255) NOT NULL , pers_id int NOT NULL ); DROP TABLE certs; DROP sequence certs_id_seq; CREATE TABLE certs ( id int NOT NULL PRIMARY KEY, cert bytea NOT NULL, pers_id int NOT NULL ); DROP TABLE referrals; DROP sequence referrals_id_seq; CREATE TABLE referrals ( id serial NOT NULL PRIMARY KEY, name varchar(255) NOT NULL, url varchar(255) NOT NULL ); ''testdb_data.sql'' : insert into institutes (id,name) values (1,'Example'); insert into persons (id,name,surname,password) values (1,'Mitya','Kovalev','mit'); insert into persons (id,name,surname) values (2,'Torvlobnor','Puzdoy'); insert into persons (id,name,surname) values (3,'Akakiy','Zinberstein'); insert into phones (id,phone,pers_id) values (1,'332-2334',1); insert into phones (id,phone,pers_id) values (2,'222-3234',1); insert into phones (id,phone,pers_id) values (3,'545-4563',2); insert into documents (id,abstract,title) values (1,'abstract1','book1'); insert into documents (id,abstract,title) values (2,'abstract2','book2'); insert into authors_docs (pers_id,doc_id) values (1,1); insert into authors_docs (pers_id,doc_id) values (1,2); insert into authors_docs (pers_id,doc_id) values (2,1); insert into referrals (id,name,url) values (1,'Referral','ldap://localhost:9012/'); insert into certs (id,cert,pers_id) values (1,decode('MIIDazCCAtSgAwIBAgIBAjANBgkqhkiG9w0BAQQFADB3MQswCQYDVQQGEwJVUzETMBEGA1UECBMKQ2FsaWZvcm5pYTEfMB0GA1UEChMWT3BlbkxEQVAgRXhhbXBsZSwgTHRkLjETMBEGA1UEAxMKRXhhbXBsZSBDQTEdMBsGCSqGSIb3DQEJARYOY2FAZXhhbXBsZS5jb20wHhcNMDMxMDE3MTYzMzE5WhcNMDQxMDE2MTYzMzE5WjB+MQswCQYDVQQGEwJVUzETMBEGA1UECBMKQ2FsaWZvcm5pYTEfMB0GA1UEChMWT3BlbkxEQVAgRXhhbXBsZSwgTHRkLjEYMBYGA1UEAxMPVXJzdWxhIEhhbXBzdGVyMR8wHQYJKoZIhvcNAQkBFhB1aGFtQGV4YW1wbGUuY29tMIGfMA0GCSqGSIb3DQEBAQUAA4GNADCBiQKBgQDuxgp5ELV9LmhxWMpV7qc4028QQT3+zzFDXhruuXE7ji2n3S3ea8bOwDtJh+qnsDe561DhHHHlgIjMKCiDEizYMpxvJPYEXmvp0huRkMgpKZgmel95BSkt6TYmJ0erS3aoimOHLEFimmnTLolNRMiWqNBvqwobx940PGwUWEePKQIDAQABo4H/MIH8MAkGA1UdEwQCMAAwLAYJYIZIAYb4QgENBB8WHU9wZW5TU0wgR2VuZXJhdGVkIENlcnRpZmljYXRlMB0GA1UdDgQWBBSjI94TbBmuDEeUUOiC37EK0Uf0XjCBoQYDVR0jBIGZMIGWgBRLbyEaNiTSkPlDsFNHLX3hwOaYI6F7pHkwdzELMAkGA1UEBhMCVVMxEzARBgNVBAgTCkNhbGlmb3JuaWExHzAdBgNVBAoTFk9wZW5MREFQIEV4YW1wbGUsIEx0ZC4xEzARBgNVBAMTCkV4YW1wbGUgQ0ExHTAbBgkqhkiG9w0BCQEWDmNhQGV4YW1wbGUuY29tggEAMA0GCSqGSIb3DQEBBAUAA4GBAIgUcARb3OlWYNbmr1nmqESuxLn16uqI1Ot6WkcICvpkdQ+Bo+R9AP05xpoXocZtKdNvBu3FNxB/jFkiOcLU2lX7Px1Ijnsjh60qVRy9HOsHCungIKlGcnXLKHmKu0y//5jds/HnaJsGcHI5JRG7CBJbW+wrwge3trJ1xHJI8prN','base64'),3); ''backsql_create.sql'' : DROP TABLE ldap_oc_mappings; DROP sequence ldap_oc_mappings_id_seq; CREATE TABLE ldap_oc_mappings ( id serial NOT NULL PRIMARY KEY, name varchar(64) NOT NULL, keytbl varchar(64) NOT NULL, keycol varchar(64) NOT NULL, create_proc varchar(255), delete_proc varchar(255), expect_return int NOT NULL default 0 ); DROP TABLE ldap_attr_mappings; DROP sequence ldap_attr_mappings_id_seq; CREATE TABLE ldap_attr_mappings ( id serial NOT NULL PRIMARY KEY, oc_map_id integer NOT NULL REFERENCES ldap_oc_mappings(id), name varchar(255) NOT NULL, sel_expr varchar(255) NOT NULL, sel_expr_u varchar(255), from_tbls varchar(255) NOT NULL, join_where varchar(255), add_proc varchar(255), delete_proc varchar(255), param_order int NOT NULL default 0, expect_return int NOT NULL default 0 ); -- entries mapping: each entry must appear in this view, with a unique DN rooted at the database naming context -- id a unique number > 0 identifying the entry, this hack only works with max 9 tables/objectClasses -- dn the DN of the entry, in "pretty" form -- oc_map_id the "ldap_oc_mappings.id" of the main objectClass of this entry (view it as the structuralObjectClass) -- parent the "ldap_entries.id" of the parent of this objectClass; 0 if it is the "suffix" of the database -- keyval the value of the "keytbl.keycol" defined for this objectClass -- the algorithm that generates the ids only allows 9 tables ... room for improvement DROP VIEW ldap_entries; CREATE VIEW ldap_entries AS SELECT 1 AS id, lower('dc=example,dc=com') AS dn, 3 AS oc_map_id, 0 AS parent, 1 AS keyval UNION SELECT cast(text(ldap_oc_mappings.id)||text(persons.id) AS integer) AS id, text('cn='||persons.name||' '||persons.surname||',dc=example,dc=com') AS dn, ldap_oc_mappings.id AS oc_map_id, 1 AS parent, persons.id AS keyval FROM persons JOIN ldap_oc_mappings ON ldap_oc_mappings.keytbl = 'persons' UNION SELECT cast(text(ldap_oc_mappings.id)||text(documents.id) AS integer) AS id, text('documentTitle='||documents.title||',dc=example,dc=com') AS dn, ldap_oc_mappings.id AS oc_map_id, 1 AS parent, documents.id AS keyval FROM documents JOIN ldap_oc_mappings ON ldap_oc_mappings.keytbl = 'documents' ORDER BY id ; -- Todo: turn this into a view DROP TABLE ldap_entry_objclasses; CREATE TABLE ldap_entry_objclasses ( entry_id integer NOT NULL, oc_name varchar(64) ); ''testdb_metadata.sql'' : -- mappings -- objectClass mappings: these may be viewed as structuralObjectClass, the ones that are used to decide how to build an entry -- id a unique number identifying the objectClass -- name the name of the objectClass; it MUST match the name of an objectClass that is loaded in slapd's schema -- keytbl the name of the table that is referenced for the primary key of an entry -- keycol the name of the column in "keytbl" that contains the primary key of an entry; the pair "keytbl.keycol" uniquely identifies an entry of objectClass "id" -- create_proc a procedure to create the entry -- delete_proc a procedure to delete the entry; it takes "keytbl.keycol" of the row to be deleted -- expect_return a bitmap that marks whether create_proc (1) and delete_proc (2) return a value or not INSERT INTO ldap_oc_mappings (id,name,keytbl,keycol) VALUES (1,'inetOrgPerson','persons','id'); INSERT INTO ldap_oc_mappings (id,name,keytbl,keycol) VALUES (2,'document','documents','id'); INSERT INTO ldap_oc_mappings (id,name,keytbl,keycol) VALUES (3,'organization','institutes','id'); -- INSERT INTO ldap_oc_mappings (id,name,keytbl,keycol) VALUES (4,'referral','referrals','id'); -- attributeType mappings: describe how an attributeType for a certain objectClass maps to the SQL data. -- id a unique number identifying the attribute -- oc_map_id the value of "ldap_oc_mappings.id" that identifies the objectClass this attributeType is defined for -- name the name of the attributeType; it MUST match the name of an attributeType that is loaded in slapd's schema -- sel_expr the expression that is used to select this attribute (the "select from ..." portion) -- from_tbls the expression that defines the table(s) this attribute is taken from (the "select ... from where ..." portion) -- join_where the expression that defines the condition to select this attribute (the "select ... where ..." portion) -- add_proc a procedure to insert the attribute; it takes the value of the attribute that is added, and the "keytbl.keycol" of the entry it is associated to -- delete_proc a procedure to delete the attribute; it takes the value of the attribute that is added, and the "keytbl.keycol" of the entry it is associated to -- param_order a mask that marks if the "keytbl.keycol" value comes before or after the value in add_proc (1) and delete_proc (2) -- expect_return a mask that marks whether add_proc (1) and delete_proc(2) are expected to return a value or not INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (1,1,'cn','text(persons.name||'' ''||persons.surname)','persons',NULL); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (2,1,'telephoneNumber','phones.phone','persons,phones','phones.pers_id=persons.id'); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (3,1,'givenName','persons.name','persons',NULL); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (4,1,'sn','persons.surname','persons',NULL); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (5,1,'userPassword','persons.password','persons','persons.password IS NOT NULL'); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (6,1,'seeAlso','seeAlso.dn','ldap_entries AS seeAlso,documents,authors_docs,persons','seeAlso.keyval=documents.id AND seeAlso.oc_map_id=2 AND authors_docs.doc_id=documents.id AND authors_docs.pers_id=persons.id'); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (7,2,'description','documents.abstract','documents',NULL); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (8,2,'documentTitle','documents.title','documents',NULL); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (9,2,'documentAuthor','documentAuthor.dn','ldap_entries AS documentAuthor,documents,authors_docs,persons','documentAuthor.keyval=persons.id AND documentAuthor.oc_map_id=1 AND authors_docs.doc_id=documents.id AND authors_docs.pers_id=persons.id'); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (10,2,'documentIdentifier','''document ''||text(documents.id)','documents',NULL); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (11,3,'o','institutes.name','institutes',NULL); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (12,3,'dc','lower(institutes.name)','institutes,ldap_entries AS dcObject,ldap_entry_objclasses AS auxObjectClass','institutes.id=dcObject.keyval AND dcObject.oc_map_id=3 AND dcObject.id=auxObjectClass.entry_id AND auxObjectClass.oc_name=''dcObject'''); -- INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (13,4,'ou','referrals.name','referrals',NULL); -- INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (14,4,'ref','referrals.url','referrals',NULL); INSERT INTO ldap_attr_mappings (id,oc_map_id,name,sel_expr,from_tbls,join_where) VALUES (15,1,'userCertificate','certs.cert','persons,certs','certs.pers_id=persons.id'); -- objectClass mapping: entries that have multiple objectClass instances are listed here with the objectClass name (view them as auxiliary objectClass) -- entry_id the "ldap_entries.id" of the entry this objectClass value must be added -- oc_name the name of the objectClass; it MUST match the name of an objectClass that is loaded in slapd's schema INSERT INTO ldap_entry_objclasses (entry_id,oc_name) VALUES (11, 'dcObject'); INSERT INTO ldap_entry_objclasses (entry_id,oc_name) VALUES (13, 'pkiUser'); --INSERT INTO ldap_entry_objclasses (entry_id,oc_name) VALUES (7,'extensibleObject'); Als Nutzer psql pgldapro pgldapro < testdb_create.sql psql pgldapro pgldapro < testdb_data.sql psql pgldapro pgldapro < backsql_create.sql psql pgldapro pgldapro < testdb_metadata.sql ===== unixODBC konfigurieren ===== odbcinst -i -d -f /usr/share/psqlodbc/odbcinst.ini.template erzeugt ''/etc/odbcinst.ini'' ''/etc/odbc.ini'' : [pgldapro] Description = Example for OpenLDAP's back-sql Driver = PostgreSQL Unicode Trace = No Database = pgldapro Servername = localhost UserName = pgldapro Password = villa Port = 5432 ;Protocol = 6.4 ReadOnly = No RowVersioning = No ShowSystemTables = No ShowOidColumn = No FakeOidIndex = No ConnSettings = ==== testen ==== ODBC: isql pgldapro pgldapro select * from persons; quit ===== slapd ===== ''/etc/default/slapd'' : SLAPD_CONF=/etc/ldap/slapd.conf ''/etc/ldap/slapd.conf'' : include /etc/ldap/schema/core.schema include /etc/ldap/schema/cosine.schema include /etc/ldap/schema/nis.schema include /etc/ldap/schema/inetorgperson.schema pidfile /var/run/slapd/slapd.pid argsfile /var/run/slapd/slapd.args loglevel none modulepath /usr/lib/ldap moduleload back_sql.la moduleload back_monitor.la sizelimit 500 tool-threads 1 access to attrs=userpassword by anonymous =x access to * by * read backend sql database sql readonly on suffix "dc=example,dc=com" rootdn "cn=Manager,dc=example,dc=com" rootpw secret dbname pgldapro dbuser pgldapro dbpasswd test upper_func "upper" strcast_func "text" concat_pattern "?||?" has_ldapinfo_dn_ru no database monitor ldapsearch -x -W -b dc=example,dc=com -H ldap://localhost -D cn=Manager,dc=example,dc=com ====== Fehlersuche ====== slapd -d -1 -f /etc/ldap/slapd.conf ''/etc/postgresql/*/*/postgresql.conf'' : log_statement = 'all' log_min_error_statement = error ====== Bugs ====== Man scheint 2 x ''database sql'' nicht nutzen zu können. ''slapd'' startet, und der erste Zugriff funktioniert auch. Aber Zugriffe auf das jeweils andere ''suffix'' nicht. ====== Doku ====== * ~/openldap-2.4.23/servers/slapd/back-sql/rdbms_depend/README * http://www.openldap.org/faq/data/cache/978.html