Creating unique Userid

  • Hi,

    I want create unique userid by rtaking first character of firstname + lastName.

    if first character of first name and last name is same then i want to increase it by 1.

    eg. john macmohan then it would be jmacmohan

    jim macmohan

    then it would be jmacmohan01 ......

    but while creating i want to check this with current table if that username is present then increase by one and also there is another check. i.e. same username should not present in the directory. i.e. another table. if same name is present there then also increase by one.

    eg.

    jack macmohan should be jmacmohan02 in our case. but if this is present in the directory table then it should be jmacmohan03.

    how can i do it. Please guide or share sample if aviliable?

    Thanks

    Abhas.

  • well you are assuming based on your formatting that you'd never have more than 10 people with the same name(xxx09);

    i'm providing an example below, but i don't think like the idea;

    id rather let people use their emails as a username, which at least ends up unique to the end user; i'd hate to comeback to some web site and not be able to remember my "username" was "Lowell312" or something(I'm talking to you, Progressive Insurance!), which was something i didn't pick or even want.

    don't get caught up on the CTE's, they are just generating random data;

    the trick is to use row number and a case statement to generate the string

    --this is just generating fake sample data.

    With MYFirstNames(FName) AS

    (

    Select 'Leonardo' UNION ALL

    Select 'Brad' UNION ALL

    Select 'Arnold' UNION ALL

    Select 'Mark' UNION ALL

    Select 'Matt' UNION ALL

    Select 'Bruce'

    ),

    MyLastNames(LName) AS

    (

    Select 'DeCaprio' UNION ALL

    Select 'Pitt' UNION ALL

    Select 'Schwarzenegger' UNION ALL

    Select 'Wahlberg' UNION ALL

    Select 'Damon' UNION ALL

    Select 'Willis'

    ), NamesWithRowNumber

    AS

    (

    SELECT TOP 10000

    row_number() over (partition by LEFT(A.FName,1),B.LName ORDER BY A.FName,B.LName) - 1 AS RW, --zero indexed

    A.FName,B.LName

    FROM MYFirstNames A

    CROSS JOIN MyLastNames B

    CROSS JOIN sys.columns

    ORDER BY NEWID()

    )

    SELECT

    CASE

    WHEN RW = 0

    THEN LEFT(FName,1)+ LName

    ELSE LEFT(FName,1) + LName + RIGHT('0000' + CONVERT(varchar,rw),4)

    END AS UserName,

    *

    FROM NamesWithRowNumber

    ORDER BY RW,UserName

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • I agree with Lowell but if you must do it, try this. It's not fully tested but may get you started.

    declare

    @ID varchar(100),

    @FirstName varchar(100),

    @LastName varchar(100),

    @Counter int,

    @RecordCounter int

    set @FirstName = 'john'

    set @LastName = 'doe'

    set @Counter = 0

    set @RecordCounter = 0

    if exists(select ID from Users where ID = left(@FirstName, 1) + @LastName)

    begin

    set @Counter += 1

    while (@RecordCounter = 0)

    begin

    set @RecordCounter = (select count(*) from Users where ID = left(@FirstName, 1) + @LastName + '0' + convert(varchar(5), @Counter))

    if @RecordCounter = 1

    begin

    set @ID = left(@FirstName, 1) + @LastName + '0' + convert(varchar(5), @Counter+1)

    set @RecordCounter = 1

    break

    end

    else

    begin

    set @ID = left(@FirstName, 1) + @LastName + '0' + convert(varchar(5), @Counter)

    set @RecordCounter = 1

    break

    end

    end

    end

    else

    begin

    set @ID = left(@FirstName, 1) + @LastName

    end

    print 'new ID is ' + convert(varchar(50), @ID)

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply