import java.lang.Integer; CREATE TABLE IF NOT EXISTS user_packets( master_key_id INTEGER NOT NULL, rank INTEGER AS Integer NOT NULL, type INTEGER, user_id TEXT, name TEXT, email TEXT, comment TEXT, attribute_data BLOB, is_primary INTEGER AS Boolean NOT NULL, is_revoked INTEGER AS Boolean NOT NULL, PRIMARY KEY(master_key_id, rank), FOREIGN KEY(master_key_id) REFERENCES keyrings_public(master_key_id) ON DELETE CASCADE ); insertUserPacket: INSERT INTO user_packets (master_key_id, rank, type, user_id, name, email, comment, attribute_data, is_primary, is_revoked) VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?); selectUserIdsByMasterKeyId: SELECT user_packets.master_key_id, user_packets.rank, user_id, name, email, comment, is_primary, is_revoked, MIN(certs.verified) AS verified_int FROM user_packets LEFT JOIN certs ON ( user_packets.master_key_id = certs.master_key_id AND user_packets.rank = certs.rank AND certs.verified > 0 ) WHERE user_packets.type IS NULL AND user_packets.is_revoked = 0 AND user_packets.master_key_id IN ? GROUP BY user_packets.master_key_id, user_packets.rank ORDER BY user_packets.master_key_id ASC,user_packets.rank ASC; selectUserIdsByMasterKeyIdAndVerification: SELECT user_packets.master_key_id, user_packets.rank, user_id, name, email, comment, is_primary, is_revoked, MIN(certs.verified) AS verified_int FROM user_packets LEFT JOIN certs ON ( user_packets.master_key_id = certs.master_key_id AND user_packets.rank = certs.rank AND certs.verified > 0 ) WHERE user_packets.type IS NULL AND user_packets.is_revoked = 0 AND user_packets.master_key_id = ? AND certs.verified = ? GROUP BY user_packets.rank ORDER BY user_packets.rank ASC; selectUserAttributesByTypeAndMasterKeyId: SELECT user_packets.master_key_id, user_packets.rank, attribute_data, is_primary, is_revoked, MIN(certs.verified) AS verified_int FROM user_packets LEFT JOIN certs ON ( user_packets.master_key_id = certs.master_key_id AND user_packets.rank = certs.rank AND certs.verified > 0 ) WHERE user_packets.type = ? AND user_packets.is_revoked = 0 AND user_packets.master_key_id = ? GROUP BY user_packets.rank ORDER BY user_packets.rank ASC; selectSpecificUserAttribute: SELECT user_packets.master_key_id, user_packets.rank, attribute_data, is_primary, is_revoked, MIN(certs.verified) AS verified_int FROM user_packets LEFT JOIN certs ON ( user_packets.master_key_id = certs.master_key_id AND user_packets.rank = certs.rank AND certs.verified > 0 ) WHERE user_packets.type = ? AND user_packets.master_key_id = ? AND user_packets.rank = ? GROUP BY user_packets.master_key_id, user_packets.rank; uidStatus: CREATE VIEW uidStatus AS SELECT user_packets.email, MIN(certs.verified) AS key_status_int, user_packets.user_id, user_packets.master_key_id, COUNT(DISTINCT user_packets.master_key_id) AS candidates FROM user_packets JOIN validMasterKeys USING (master_key_id) LEFT JOIN certs ON (certs.master_key_id = user_packets.master_key_id AND certs.rank = user_packets.rank AND certs.verified > 0) WHERE user_packets.email IS NOT NULL GROUP BY user_packets.email; selectUserIdStatusByEmail: SELECT * FROM uidStatus WHERE email IN ?; selectUserIdStatusByEmailLike: SELECT * FROM uidStatus WHERE email LIKE ?;