• So you have a Database that is not part of the Availability Group?
    Is the Database ONLINE?
    Is the Database ready to be added to the Availability Group?
                   - Or the Database is corrupted?
                   -Or the Database needs to be Restored from backup for whatever reason?

    Can you be more specific on your question. I'll make an assumption.

    1. Your database is ONLINE and ready to be added to the Availability Group. First time adding this database to Availability Group.
    2. The availability Group is Healthy and there are no issues. Shares are properly configured for Synchronization.
    3. You are using either SQL 2012 or 2014.    SQL 2016 makes it a little bit easier with "SEEDING".
    4. Go to Always ON High Availability > Availability Groups > Select the GROUP > Right click on Availability Databases > "Add Database"
               - Here it will tell you if it "Meets Prerequisites"
               - Or needs "Full Recovery"
               - or needs a "Backup"
    5. If it meets Prerequisites then you can add it 
    6. It will ask you to connect to the secondary node
    7. in the Select Data Synchronization it will ask you to choose one of the following:
                      - Specify the file share path   (Location of Full Database and Log backup)      - I usually do this one
                       - Join Only     (you have restored database  and log backup to each secondary server)          - I've had problems with this one
                      - Skip initial Synchronization    (perform own DB/log backup to primary )                                -never done this one
    8.  It will perform a validation... if there are errors it will tell you here. Errors such as
                   - problems with shared location
                   - Disk space
                   - Does database already exists in secondary node or files already exists there
                   - Compatibility of file locations
     9. Once it passes the validation then you are ready to FINISH and make it part of the availability Group.
            It will Synchronize and add it to the secondary node.Things to know : 
    Server 1 : developmentsql1
    Server2 : developmentsql2
    Database to be added : MyDatabase
    Availability Group : DEVSQLGRP
    Shared backup location 1 : \\Developmentsql1\SharedLocation\
    Shared Backup location: \\Developmentsql2\SharedLocation\

    SCRIPTED BELOW..
    --- YOU MUST EXECUTE THE FOLLOWING SCRIPT IN SQLCMD MODE.
    :Connect developmentsql1  --whatever name of your primary server

    USE [master]
    GO
    ALTER AVAILABILITY GROUP [DEVSQLGRP]   --whatever GROUP name you have
    ADD DATABASE [MyDatabase];  --whatever Server
    GO
    :Connect developmentsql1
    BACKUP DATABASE [MyDatabase] TO  DISK = N'\\Developmentsql1\SharedLocation\developmentsql.bak' WITH  COPY_ONLY, FORMAT, INIT, SKIP, REWIND, NOUNLOAD, COMPRESSION,  STATS = 5
    GO
    :Connect developmentsql2
    RESTORE DATABASE [PeopleAdmin] FROM  DISK = N'\\Developmentsql2\SharedLocation\developmentsql.bak' WITH  NORECOVERY,  NOUNLOAD,  STATS = 5
    GO
    :Connect developmentsql1
    BACKUP LOG [PeopleAdmin] TO  DISK = N'\\Developmentsql1\SharedLocation\developmentsql.trn' WITH NOFORMAT, INIT, NOSKIP, REWIND, NOUNLOAD, COMPRESSION,  STATS = 5
    GO
    :Connect developmentsql2
    RESTORE LOG [PeopleAdmin] FROM  DISK = N'\\Developmentsql2\SharedLocation\developmentsql.trn' WITH  NORECOVERY,  NOUNLOAD,  STATS = 5
    GO
    :Connect developmentsql2
    -- Wait for the replica to start communicating
    begin try
    declare @conn bit
    declare @count int
    declare @replica_id uniqueidentifier
    declare @group_id uniqueidentifier
    set @conn = 0
    set @count = 30 -- wait for 5 minutes
    if (serverproperty('IsHadrEnabled') = 1)
     and (isnull((select member_state from master.sys.dm_hadr_cluster_members where upper(member_name COLLATE Latin1_General_CI_AS) = upper(cast(serverproperty('ComputerNamePhysicalNetBIOS') as nvarchar(256)) COLLATE Latin1_General_CI_AS)), 0) <> 0)
     and (isnull((select state from master.sys.database_mirroring_endpoints), 1) = 0)
    begin
        select @group_id = ags.group_id from master.sys.availability_groups as ags where name = N'DEVSQLGRP'
     select @replica_id = replicas.replica_id from master.sys.availability_replicas as replicas where upper(replicas.replica_server_name COLLATE Latin1_General_CI_AS) = upper(@@SERVERNAME COLLATE Latin1_General_CI_AS) and group_id = @group_id
     while @conn <> 1 and @count > 0
     begin
      set @conn = isnull((select connected_state from master.sys.dm_hadr_availability_replica_states as states where states.replica_id = @replica_id), 1)
      if @conn = 1
      begin
       -- exit loop when the replica is connected, or if the query cannot find the replica status
       break
      end
      waitfor delay '00:00:10'
      set @count = @count - 1
     end
    end
    end try
    begin catch
     -- If the wait loop fails, do not stop execution of the alter database statement
    end catch
    ALTER DATABASE [MyDatabase] SET HADR AVAILABILITY GROUP = [DEVSQLGRP];
    GO
    GO