CONSTRAINT passwd_type_once_per_user UNIQUE (usr, passwd_type)
);
--- actor.passwd is not IDL-accessible, so the application
--- needs a way to retrieve the salt via cstore.
-CREATE OR REPLACE FUNCTION actor.passwd_salt(pw_user INTEGER, pw_type TEXT)
+-- actor.passwd is not IDL-accessible. This function gives the
+-- application access to the salt. If the password type of "main"
+-- is requested and no password exists in actor.passwd, the user's
+-- existing password is migrated and the new salt is returned.
+CREATE OR REPLACE FUNCTION actor.passwd_salt(pw_usr INTEGER, pw_type TEXT)
RETURNS TEXT AS $$
- SELECT salt FROM actor.passwd
- WHERE usr = $1 AND passwd_type = $2;
-$$ STRICT LANGUAGE SQL;
+DECLARE
+ pw_salt TEXT;
+BEGIN
+
+ SELECT INTO pw_salt salt FROM actor.passwd
+ WHERE usr = pw_usr AND passwd_type = pw_type;
+
+ IF FOUND THEN
+ RETURN pw_salt;
+ END IF;
+
+ IF pw_type = 'main' THEN
+ RETURN actor.migrate_passwd(pw_usr);
+ END IF;
+
+ -- Only 'main' passwords are auto-migrated.
+ RETURN NULL;
+
+END;
+$$ LANGUAGE PLPGSQL;
-- Migrates actor.usr.passwd to actor.passwd with
--- password type 'main' for every user.
--- Could drop this after the initial migration.
-CREATE OR REPLACE FUNCTION actor.migrate_all_passwd() RETURNS VOID AS $$
+-- password type 'main' for every user. Returns the salt.
+CREATE OR REPLACE FUNCTION
+ actor.migrate_passwd(pw_usr INTEGER) RETURNS TEXT AS $$
DECLARE
pw_salt TEXT;
usr_obj actor.usr%ROWTYPE;
BEGIN
- FOR usr_obj IN SELECT * FROM actor.usr LOOP
- pw_salt := gen_salt('bf', 10); -- TODO: configurable?
-
- INSERT INTO actor.passwd (usr, passwd_type, salt, passwd)
- VALUES (
- usr_obj.id,
- 'main', -- only 'main' is migrated
- pw_salt,
- CRYPT(MD5(usr_obj.passwd || pw_salt), pw_salt)
- );
-
- -- OR DROP passwd column after loop
- UPDATE actor.usr SET passwd = '' WHERE id = usr_obj.id;
- END LOOP;
+
+ SELECT INTO usr_obj * FROM actor.usr WHERE id = pw_usr;
+ pw_salt := gen_salt('bf', 14); -- TODO: configurable?
+
+ INSERT INTO actor.passwd (usr, passwd_type, salt, passwd)
+ VALUES (
+ usr_obj.id,
+ 'main', -- only 'main' is migrated
+ pw_salt,
+ CRYPT(MD5(usr_obj.passwd || pw_salt), pw_salt)
+ );
+
+ -- OR DROP passwd column after loop
+ UPDATE actor.usr SET passwd = '' WHERE id = usr_obj.id;
+ RETURN pw_salt;
END;
$$ LANGUAGE PLPGSQL;
pw_salt TEXT;
BEGIN
- SELECT INTO pw_salt salt FROM actor.passwd
- WHERE usr = pw_usr AND passwd_type = pw_type;
+ pw_salt := actor.passwd_salt(pw_usr, pw_type);
- IF NOT FOUND THEN
- -- No such user or password-type
+ IF pw_salt IS NULL THEN
+ -- Requested password does not exist in actor.passwd
RETURN FALSE;
END IF;
SELECT TRUE AS verify_old_pw
FROM actor.usr WHERE id = 187 AND passwd = MD5('montyc1234');
--- migrate all passwords
-SELECT actor.migrate_all_passwd();
+-- This should result in a migration
+SELECT actor.passwd_salt(187, 'main') AS new_salt;
+-- Directly migrate
+-- SELECT actor.migrate_passwd(187);
-- see what the new password row looks like
SELECT * FROM actor.passwd WHERE usr = 187;